ADD INDEX

ALTER TABLE.. ADD INDEX 语句用于在已有表中添加一个索引。在 TiDB 中,ADD INDEX 为在线操作,不会阻塞表中的数据读写。

语法图

AlterTableStmt
ALTERIGNORETABLETableNameAddIndexSpec,
AddIndexSpec
ADDPRIMARYKEYKEYINDEXIF NOT EXISTSUNIQUEKEYINDEXIdentifierUSINGIdentifierTYPEIndexTypeFULLTEXTKEYINDEXIndexName(IndexPartSpecification,)IndexOption
IndexPartSpecification
ColumnName(LengthNum)(Expression)ASCDESC
IndexOption
KEY_BLOCK_SIZE=LengthNumIndexTypeWITHPARSERIdentifierCOMMENTstringLitVISIBLEINVISIBLE
IndexType
BTREEHASHRTREE

示例

CREATE TABLE t1 (id INT NOT NULL PRIMARY KEY AUTO_INCREMENT, c1 INT NOT NULL);
Query OK, 0 rows affected (0.11 sec)
INSERT INTO t1 (c1) VALUES (1),(2),(3),(4),(5);
Query OK, 5 rows affected (0.03 sec) Records: 5 Duplicates: 0 Warnings: 0
EXPLAIN SELECT * FROM t1 WHERE c1 = 3;
+-------------------------+----------+-----------+---------------+--------------------------------+ | id | estRows | task | access object | operator info | +-------------------------+----------+-----------+---------------+--------------------------------+ | TableReader_7 | 10.00 | root | | data:Selection_6 | | └─Selection_6 | 10.00 | cop[tikv] | | eq(test.t1.c1, 3) | | └─TableFullScan_5 | 10000.00 | cop[tikv] | table:t1 | keep order:false, stats:pseudo | +-------------------------+----------+-----------+---------------+--------------------------------+ 3 rows in set (0.00 sec)
ALTER TABLE t1 ADD INDEX (c1);
Query OK, 0 rows affected (0.30 sec)
EXPLAIN SELECT * FROM t1 WHERE c1 = 3;
+------------------------+---------+-----------+------------------------+---------------------------------------------+ | id | estRows | task | access object | operator info | +------------------------+---------+-----------+------------------------+---------------------------------------------+ | IndexReader_6 | 0.01 | root | | index:IndexRangeScan_5 | | └─IndexRangeScan_5 | 0.01 | cop[tikv] | table:t1, index:c1(c1) | range:[3,3], keep order:false, stats:pseudo | +------------------------+---------+-----------+------------------------+---------------------------------------------+ 2 rows in set (0.00 sec)

MySQL 兼容性

  • 为了兼容 MySQL,TiDB 在语法上支持 HASHBTREERTREE 等索引类型,但会忽略它们。
  • 不支持 SPATIAL 索引。
  • TiDB 支持解析 FULLTEXT 语法,但不支持使用 FULLTEXT 索引。
  • 不支持降序索引(类似于 MySQL 5.7)。
  • 无法向表中添加 CLUSTERED 类型的 PRIMARY KEY。要了解关于 CLUSTERED 主键的详细信息,请参考聚簇索引

另请参阅

文档内容是否有帮助?