ADD INDEX
The ALTER TABLE.. ADD INDEX statement adds an index to an existing table. This operation is online in TiDB, which means that neither reads or writes to the table are blocked by adding an index.
Synopsis
- AlterTableStmt
- AddIndexSpec
- IndexPartSpecification
- IndexOption
- IndexType
AlterTableStmt
::= 'ALTER' 'IGNORE'? 'TABLE' TableName AddIndexSpec ( ',' AddIndexSpec )*
AddIndexSpec
::= 'ADD' ( ( 'PRIMARY' 'KEY' | ( 'KEY' | 'INDEX' ) 'IF NOT EXISTS'? | 'UNIQUE' ( 'KEY' | 'INDEX' )? ) ( ( Identifier? 'USING' | Identifier 'TYPE' ) IndexType )? | 'FULLTEXT' ( 'KEY' | 'INDEX' )? IndexName ) '(' IndexPartSpecification ( ',' IndexPartSpecification )* ')' IndexOption*
IndexPartSpecification
::= ( ColumnName ( '(' LengthNum ')' )? | '(' Expression ')' ) ( 'ASC' | 'DESC' )
IndexOption
::= 'KEY_BLOCK_SIZE' '='? LengthNum
| 'USING' IndexType
| 'WITH' 'PARSER' Identifier
| 'COMMENT' stringLit
| 'VISIBLE'
| 'INVISIBLE'
| 'GLOBAL'
| 'LOCAL'
IndexType
::= 'BTREE'
| 'HASH'
| 'RTREE'
Examples
mysql> CREATE TABLE t1 (id INT NOT NULL PRIMARY KEY AUTO_INCREMENT, c1 INT NOT NULL);
Query OK, 0 rows affected (0.11 sec)
mysql> INSERT INTO t1 (c1) VALUES (1),(2),(3),(4),(5);
Query OK, 5 rows affected (0.03 sec)
Records: 5 Duplicates: 0 Warnings: 0
mysql> 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)
mysql> ALTER TABLE t1 ADD INDEX (c1);
Query OK, 0 rows affected (0.30 sec)
mysql> 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 compatibility
TiDB accepts index types such as
HASH,BTREEandRTREEin syntax for compatibility with MySQL, but ignores them.SPATIALindexes are not supported.TiDB Self-Managed and TiDB Cloud Dedicated support parsing the
FULLTEXTsyntax but do not support using theFULLTEXTindexes.Descending indexes are not supported (similar to MySQL 5.7).
Adding the primary key of the
CLUSTEREDtype to a table is not supported. For more details about the primary key of theCLUSTEREDtype, refer to clustered index.Setting a
PRIMARY KEYorUNIQUE INDEXas a global index with theGLOBALindex option is a TiDB extension for partitioned tables and is not compatible with MySQL.