-
Notifications
You must be signed in to change notification settings - Fork 111
table_exists()
xiaoboluo768 edited this page Jun 9, 2020
·
2 revisions
-
检查指定表是否存在且是否是普通表、临时表、视图,传入两个入参(in类型)和一个出参(out类型),入参为库名和表名,出参为返回表类型,如果表存在则会返回该表的类型(TEMPORARY、BASE TABLE、VIEW),如果不存在或者不是临时表、不是基表、不是视图则返回空值
- 该存储过程也作为部分存储过程的辅助存储过程来返回表是否存在,以及返回表的类型
- 此存储过程在MySQL 5.7.9中新增
- 注意:如果同时存在给定名称的基表和临时表,则会返回给定表名是一个临时表(不光是该存储过程是这样,show create table等语句也是优先返回临时表的信息)
-
参数:
- in_db VARCHAR(64):表示要检查的表所在的数据库的名称
- in_table VARCHAR(64):表示要检查是否存在的表名称
- out_exists ENUM('','BASE TABLE','VIEW','TEMPORARY'):返回值。这是一个OUT类型参数,因此它必须是一个可以存储表类型值的变量(虽然该参数是出参,但是在调用存储过程时需要使用变量的形式传入),返回值有以下几种:
- '':表不存在,或者该表不是基表、临时表、视图
- BASE TABLE:给定表名经过检查发现是一个基表(永久表)
- VIEW:给定表名经过检查发现是一个视图
- TEMPORARY:给定表名经过检查发现是一个临时表
-
定义语句
DROP PROCEDURE IF EXISTS table_exists;
DELIMITER $$
CREATE DEFINER='root'@'localhost' PROCEDURE table_exists (
IN in_db VARCHAR(64), IN in_table VARCHAR(64),
OUT out_exists ENUM('', 'BASE TABLE', 'VIEW', 'TEMPORARY')
)
COMMENT '
Description
-----------
Tests whether the table specified in in_db and in_table exists either as a regular
table, or as a temporary table. The returned value corresponds to the table that
will be used, so if there''s both a temporary and a permanent table with the given
name, then ''TEMPORARY'' will be returned.
Parameters
-----------
in_db (VARCHAR(64)):
The database name to check for the existance of the table in.
in_table (VARCHAR(64)):
The name of the table to check the existance of.
out_exists ENUM('''', ''BASE TABLE'', ''VIEW'', ''TEMPORARY''):
The return value: whether the table exists. The value is one of:
* '''' - the table does not exist neither as a base table, view, nor temporary table.
* ''BASE TABLE'' - the table name exists as a permanent base table table.
* ''VIEW'' - the table name exists as a view.
* ''TEMPORARY'' - the table name exists as a temporary table.
Example
--------
mysql> CREATE DATABASE db1;
Query OK, 1 row affected (0.07 sec)
mysql> use db1;
Database changed
mysql> CREATE TABLE t1 (id INT PRIMARY KEY);
Query OK, 0 rows affected (0.08 sec)
mysql> CREATE TABLE t2 (id INT PRIMARY KEY);
Query OK, 0 rows affected (0.08 sec)
mysql> CREATE view v_t1 AS SELECT * FROM t1;
Query OK, 0 rows affected (0.00 sec)
mysql> CREATE TEMPORARY TABLE t1 (id INT PRIMARY KEY);
Query OK, 0 rows affected (0.00 sec)
mysql> CALL sys.table_exists(''db1'', ''t1'', @exists); SELECT @exists;
Query OK, 0 rows affected (0.00 sec)
+------------+
| @exists |
+------------+
| TEMPORARY |
+------------+
1 row in set (0.00 sec)
mysql> CALL sys.table_exists(''db1'', ''t2'', @exists); SELECT @exists;
Query OK, 0 rows affected (0.00 sec)
+------------+
| @exists |
+------------+
| BASE TABLE |
+------------+
1 row in set (0.01 sec)
mysql> CALL sys.table_exists(''db1'', ''v_t1'', @exists); SELECT @exists;
Query OK, 0 rows affected (0.00 sec)
+---------+
| @exists |
+---------+
| VIEW |
+---------+
1 row in set (0.00 sec)
mysql> CALL sys.table_exists(''db1'', ''t3'', @exists); SELECT @exists;
Query OK, 0 rows affected (0.01 sec)
+---------+
| @exists |
+---------+
| |
+---------+
1 row in set (0.00 sec)
'
SQL SECURITY INVOKER
NOT DETERMINISTIC
CONTAINS SQL
BEGIN
DECLARE v_error BOOLEAN DEFAULT FALSE;
DECLARE CONTINUE HANDLER FOR 1050 SET v_error = TRUE;
DECLARE CONTINUE HANDLER FOR 1146 SET v_error = TRUE;
SET out_exists = '';
-- Verify whether the table name exists as a normal table
IF (EXISTS(SELECT 1 FROM information_schema.TABLES WHERE TABLE_SCHEMA = in_db AND TABLE_NAME = in_table)) THEN
-- Unfortunately the only way to determine whether there is also a temporary table is to try to create
-- a temporary table with the same name. If it succeeds the table didn't exist as a temporary table.
SET @sys.tmp.table_exists.SQL = CONCAT('CREATE TEMPORARY TABLE `', in_db, '`.`', in_table, '` (id INT PRIMARY KEY)');
PREPARE stmt_create_table FROM @sys.tmp.table_exists.SQL;
EXECUTE stmt_create_table;
DEALLOCATE PREPARE stmt_create_table;
IF (v_error) THEN
SET out_exists = 'TEMPORARY';
ELSE
-- The temporary table was created, i.e. it didn't exist. Remove it again so we don't leave garbage around.
SET @sys.tmp.table_exists.SQL = CONCAT('DROP TEMPORARY TABLE `', in_db, '`.`', in_table, '`');
PREPARE stmt_drop_table FROM @sys.tmp.table_exists.SQL;
EXECUTE stmt_drop_table;
DEALLOCATE PREPARE stmt_drop_table;
SET out_exists = (SELECT TABLE_TYPE FROM information_schema.TABLES WHERE TABLE_SCHEMA = in_db AND TABLE_NAME = in_table);
END IF;
ELSE
-- Check whether a temporary table exists with the same name.
-- If it does it's possible to SELECT from the table without causing an error.
-- If it does not exist even a PREPARE using the table will fail.
SET @sys.tmp.table_exists.SQL = CONCAT('SELECT COUNT(*) FROM `', in_db, '`.`', in_table, '`');
PREPARE stmt_select FROM @sys.tmp.table_exists.SQL;
IF (NOT v_error) THEN
DEALLOCATE PREPARE stmt_select;
SET out_exists = 'TEMPORARY';
END IF;
END IF;
END$$
DELIMITER ;
上一篇: statement_performance_analyzer()存储过程 | 下一篇: extract_schema_from_file_name()函数
- 验证、测试、整理:罗小波
- QQ:309969177
- 提示:本系列文章的主体结构遵循Oracle MySQL 官方 5.7 手册中,关于information_schema、mysql schema、performance_schema、sys schema的章节结构体系,并额外添加了一些验证、测试数据。鉴于本人精力和能力有限,难免出现一些纰漏,欢迎大家踊跃指正!