ALTER INDEX
ALTER INDEX
语句用于修改索引的可见性,可以将索引设置为 Visible
或者 Invisible
。设置为 Invisible
的索引即不可见索引 (Invisible Index) 由 DML 语句维护,不会被查询优化器使用。
语法图
- AlterTableStmt
- AlterIndexSpec
AlterTableStmt
::= 'ALTER' 'IGNORE'? 'TABLE' TableName AlterIndexSpec ( ',' AlterIndexSpec )*
AlterIndexSpec
::= 'ALTER' 'INDEX' Identifier ( 'VISIBLE' | 'INVISIBLE' )
示例
可以通过 ALTER TABLE ... ALTER INDEX ...
语句,修改索引的可见性:
CREATE TABLE t1 (c1 INT, UNIQUE(c1));
ALTER TABLE t1 ALTER INDEX c1 INVISIBLE;
Query OK, 0 rows affected (0.02 sec)
SHOW CREATE TABLE t1;
+-------+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+
| Table | Create Table
|
+-------+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+
| t1 | CREATE TABLE `t1` (
`c1` int(11) DEFAULT NULL,
UNIQUE KEY `c1` (`c1`) /*!80000 INVISIBLE */
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_bin |
+-------+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+
1 row in set (0.00 sec)
优化器将无法使用 c1
这个不可见的索引:
EXPLAIN SELECT c1 FROM t1 ORDER BY c1;
+-------------------------+----------+-----------+---------------+--------------------------------+
| id | estRows | task | access object | operator info |
+-------------------------+----------+-----------+---------------+--------------------------------+
| Sort_4 | 10000.00 | root | | test.t1.c1:asc |
| └─TableReader_8 | 10000.00 | root | | data:TableFullScan_7 |
| └─TableFullScan_7 | 10000.00 | cop[tikv] | table:t1 | keep order:false, stats:pseudo |
+-------------------------+----------+-----------+---------------+--------------------------------+
3 rows in set (0.00 sec)
作为对比,c2 是可见的索引,优化器将可以使用索引:
EXPLAIN SELECT c2 FROM t1 ORDER BY c2;
+------------------------+----------+-----------+------------------------+-------------------------------+
| id | estRows | task | access object | operator info |
+------------------------+----------+-----------+------------------------+-------------------------------+
| IndexReader_13 | 10000.00 | root | | index:IndexFullScan_12 |
| └─IndexFullScan_12 | 10000.00 | cop[tikv] | table:t1, index:c2(c2) | keep order:true, stats:pseudo |
+------------------------+----------+-----------+------------------------+-------------------------------+
2 rows in set (0.00 sec)
即使用 SQL Hint USE INDEX
强制使用索引,优化器也无法使用不可见索引,否则 SQL 语句会报错:
SELECT * FROM t1 USE INDEX(c1);
ERROR 1176 (42000): Key 'c1' doesn't exist in table 't1'
ALTER TABLE t1 DROP INDEX c1;
Query OK, 0 rows affected (0.02 sec)
MySQL 兼容性
- TiDB 中的不可见索引是基于 MySQL 8.0 中的同等特性构建的。
- 与 MySQL 类似,TiDB 不允许将主键索引设为不可见。
- MySQL 中提供的优化器开关
use_invisible_indexes=on
可将所有的不可见索引重新设为可见。该功能在 TiDB 中不可用。