ANALYZE
This statement updates the statistics that TiDB builds on tables and indexes. It is recommended to run ANALYZE
after performing a large batch update or import of records, or when you notice that query execution plans are sub-optimal.
TiDB will also automatically update its statistics over time as it discovers that they are inconsistent with its own estimates.
Currently, TiDB collects statistical information in two ways: full collection (implemented using the ANALYZE TABLE
statement) and incremental collection (implemented using the ANALYZE INCREMENTAL TABLE
statement). For detailed usage of these two statements, refer to introduction to statistics
Synopsis
- AnalyzeTableStmt
- TableNameList
- TableName
AnalyzeTableStmt ::=
'ANALYZE' ( 'TABLE' ( TableNameList | TableName ( 'INDEX' IndexNameList | 'PARTITION' PartitionNameList ( 'INDEX' IndexNameList )? ) ) | 'INCREMENTAL' 'TABLE' TableName ( 'PARTITION' PartitionNameList )? 'INDEX' IndexNameList ) AnalyzeOptionListOpt
TableNameList ::=
TableName (',' TableName)*
TableName ::=
Identifier ( '.' Identifier )?
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> 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 | 10.00 | root | | index:IndexRangeScan_5 |
| └─IndexRangeScan_5 | 10.00 | cop[tikv] | table:t1, index:c1(c1) | range:[3,3], keep order:false, stats:pseudo |
+------------------------+---------+-----------+------------------------+---------------------------------------------+
2 rows in set (0.00 sec)
mysql> analyze table t1;
Query OK, 0 rows affected (0.13 sec)
mysql> EXPLAIN SELECT * FROM t1 WHERE c1 = 3;
+------------------------+---------+-----------+------------------------+-------------------------------+
| id | estRows | task | access object | operator info |
+------------------------+---------+-----------+------------------------+-------------------------------+
| IndexReader_6 | 1.00 | root | | index:IndexRangeScan_5 |
| └─IndexRangeScan_5 | 1.00 | cop[tikv] | table:t1, index:c1(c1) | range:[3,3], keep order:false |
+------------------------+---------+-----------+------------------------+-------------------------------+
2 rows in set (0.00 sec)
MySQL compatibility
TiDB differs from MySQL in both the statistics it collects and how it makes use of statistics during query execution. While this statement is syntactically similar to MySQL, the following differences apply:
- TiDB might not include very recently committed changes when running
ANALYZE TABLE
. After a batch-update of rows, you might need tosleep(1)
before executingANALYZE TABLE
in order for the statistics update to reflect these changes. #16570. ANALYZE TABLE
takes significantly longer to execute in TiDB than MySQL. This performance difference can be partially mitigated by enabling fast analyze withSET GLOBAL tidb_enable_fast_analyze=1
. Fast analyze makes use of sampling, leading to less accurate statistics. Its usage is still considered experimental.
MySQL does not support the ANALYZE INCREMENTAL TABLE
statement. TiDB supports incremental collection of statistics. For detailed usage, refer to incremental collection.