title: ADD INDEX summary: TiDB 数据库中 ADD INDEX 的使用概况。

ADD INDEX

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

语法图

  1. AlterTableStmt ::=
  2. 'ALTER' IgnoreOptional 'TABLE' TableName ( AlterTableSpecListOpt AlterTablePartitionOpt | 'ANALYZE' 'PARTITION' PartitionNameList ( 'INDEX' IndexNameList )? AnalyzeOptionListOpt )
  3. AlterTableSpec ::=
  4. TableOptionList
  5. | 'SET' 'TIFLASH' 'REPLICA' LengthNum LocationLabelList
  6. | 'CONVERT' 'TO' CharsetKw ( CharsetName | 'DEFAULT' ) OptCollate
  7. | 'ADD' ( ColumnKeywordOpt IfNotExists ( ColumnDef ColumnPosition | '(' TableElementList ')' ) | Constraint | 'PARTITION' IfNotExists NoWriteToBinLogAliasOpt ( PartitionDefinitionListOpt | 'PARTITIONS' NUM ) )
  8. | ( ( 'CHECK' | 'TRUNCATE' ) 'PARTITION' | ( 'OPTIMIZE' | 'REPAIR' | 'REBUILD' ) 'PARTITION' NoWriteToBinLogAliasOpt ) AllOrPartitionNameList
  9. | 'COALESCE' 'PARTITION' NoWriteToBinLogAliasOpt NUM
  10. | 'DROP' ( ColumnKeywordOpt IfExists ColumnName RestrictOrCascadeOpt | 'PRIMARY' 'KEY' | 'PARTITION' IfExists PartitionNameList | ( KeyOrIndex IfExists | 'CHECK' ) Identifier | 'FOREIGN' 'KEY' IfExists Symbol )
  11. | 'EXCHANGE' 'PARTITION' Identifier 'WITH' 'TABLE' TableName WithValidationOpt
  12. | ( 'IMPORT' | 'DISCARD' ) ( 'PARTITION' AllOrPartitionNameList )? 'TABLESPACE'
  13. | 'REORGANIZE' 'PARTITION' NoWriteToBinLogAliasOpt ReorganizePartitionRuleOpt
  14. | 'ORDER' 'BY' AlterOrderItem ( ',' AlterOrderItem )*
  15. | ( 'DISABLE' | 'ENABLE' ) 'KEYS'
  16. | ( 'MODIFY' ColumnKeywordOpt IfExists | 'CHANGE' ColumnKeywordOpt IfExists ColumnName ) ColumnDef ColumnPosition
  17. | 'ALTER' ( ColumnKeywordOpt ColumnName ( 'SET' 'DEFAULT' ( SignedLiteral | '(' Expression ')' ) | 'DROP' 'DEFAULT' ) | 'CHECK' Identifier EnforcedOrNot | 'INDEX' Identifier IndexInvisible )
  18. | 'RENAME' ( ( 'COLUMN' | KeyOrIndex ) Identifier 'TO' Identifier | ( 'TO' | '='? | 'AS' ) TableName )
  19. | LockClause
  20. | AlgorithmClause
  21. | 'FORCE'
  22. | ( 'WITH' | 'WITHOUT' ) 'VALIDATION'
  23. | 'SECONDARY_LOAD'
  24. | 'SECONDARY_UNLOAD'
  25. Constraint ::=
  26. ConstraintKeywordOpt ConstraintElem
  27. ConstraintKeywordOpt ::=
  28. ( 'CONSTRAINT' Symbol? )?
  29. ConstraintElem ::=
  30. ( ( 'PRIMARY' 'KEY' | KeyOrIndex IfNotExists | 'UNIQUE' KeyOrIndexOpt ) IndexNameAndTypeOpt | 'FULLTEXT' KeyOrIndexOpt IndexName ) '(' IndexPartSpecificationList ')' IndexOptionList
  31. | 'FOREIGN' 'KEY' IfNotExists IndexName '(' IndexPartSpecificationList ')' ReferDef
  32. | 'CHECK' '(' Expression ')' EnforcedOrNotOpt
  33. IndexNameAndTypeOpt ::=
  34. IndexName ( 'USING' IndexTypeName )?
  35. | Identifier 'TYPE' IndexTypeName
  36. IndexPartSpecificationList ::=
  37. IndexPartSpecification ( ',' IndexPartSpecification )*
  38. IndexPartSpecification ::=
  39. ( ColumnName OptFieldLen | '(' Expression ')' ) Order
  40. IndexOptionList ::=
  41. IndexOption*
  42. IndexOption ::=
  43. 'KEY_BLOCK_SIZE' '='? LengthNum
  44. | IndexType
  45. | 'WITH' 'PARSER' Identifier
  46. | 'COMMENT' stringLit
  47. | IndexInvisible
  48. KeyOrIndex ::=
  49. 'KEY'
  50. | 'INDEX'
  51. IndexKeyTypeOpt ::=
  52. ( 'UNIQUE' | 'SPATIAL' | 'FULLTEXT' )?
  53. IndexInvisible ::=
  54. 'VISIBLE'
  55. | 'INVISIBLE'
  56. IndexTypeName ::=
  57. 'BTREE'
  58. | 'HASH'
  59. | 'RTREE'

示例

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

MySQL 兼容性

  • 不支持 FULLTEXTHASHSPATIAL 索引。
  • 不支持 VISIBLE/INVISIBLE 索引(目前只有 master 分支上真正支持此功能)。
  • 不支持降序索引(类似于 MySQL 5.7)。
  • 目前尚不支持在一条中同时添加多个索引。
  • 无法向表中添加 CLUSTERED 类型的 PRIMARY KEY。要了解关于 CLUSTERED 主键的详细信息,请参考聚簇索引

另请参阅