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.

> **Note:** > > For [TiDB Cloud Dedicated](/tidb-cloud/select-cluster-tier.md#tidb-cloud-dedicated) clusters with 4 vCPU, it is recommended to manually disable [`tidb_ddl_enable_fast_reorg`](/system-variables.md#tidb_ddl_enable_fast_reorg-new-in-v630) to prevent resource limitations from affecting cluster stability during index creation. Disabling this setting allows indexes to be created using transactions, which reduces the overall impact on the cluster.

Synopsis

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

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

  • FULLTEXT, HASH and SPATIAL indexes are not supported.
  • Descending indexes are not supported (similar to MySQL 5.7).
  • Adding the primary key of the CLUSTERED type to a table is not supported. For more details about the primary key of the CLUSTERED type, refer to clustered index.

See also

Was this page helpful?