Sign InTry Free

Explain Statements That Use Indexes

TiDB supports several operators which make use of indexes to speed up query execution:

The examples in this document are based on the following sample data:

CREATE TABLE t1 ( id INT NOT NULL PRIMARY KEY auto_increment, intkey INT NOT NULL, pad1 VARBINARY(1024), INDEX (intkey) ); INSERT INTO t1 SELECT NULL, FLOOR(RAND()*1024), RANDOM_BYTES(1024) FROM dual; INSERT INTO t1 SELECT NULL, FLOOR(RAND()*1024), RANDOM_BYTES(1024) FROM t1 a JOIN t1 b JOIN t1 c LIMIT 10000; INSERT INTO t1 SELECT NULL, FLOOR(RAND()*1024), RANDOM_BYTES(1024) FROM t1 a JOIN t1 b JOIN t1 c LIMIT 10000; INSERT INTO t1 SELECT NULL, FLOOR(RAND()*1024), RANDOM_BYTES(1024) FROM t1 a JOIN t1 b JOIN t1 c LIMIT 10000;

IndexLookup

TiDB uses the IndexLookup operator when retrieving data from a secondary index. In this case, the following queries will all use the IndexLookup operator on the intkey index:

EXPLAIN SELECT * FROM t1 WHERE intkey = 123; EXPLAIN SELECT * FROM t1 WHERE intkey < 10; EXPLAIN SELECT * FROM t1 WHERE intkey BETWEEN 300 AND 310; EXPLAIN SELECT * FROM t1 WHERE intkey IN (123,29,98); EXPLAIN SELECT * FROM t1 WHERE intkey >= 99 AND intkey <= 103;
+-------------------------------+---------+-----------+--------------------------------+-----------------------------------+ | id | estRows | task | access object | operator info | +-------------------------------+---------+-----------+--------------------------------+-----------------------------------+ | IndexLookUp_10 | 1.00 | root | | | | ├─IndexRangeScan_8(Build) | 1.00 | cop[tikv] | table:t1, index:intkey(intkey) | range:[123,123], keep order:false | | └─TableRowIDScan_9(Probe) | 1.00 | cop[tikv] | table:t1 | keep order:false | +-------------------------------+---------+-----------+--------------------------------+-----------------------------------+ 3 rows in set (0.00 sec) +-------------------------------+---------+-----------+--------------------------------+-----------------------------------+ | id | estRows | task | access object | operator info | +-------------------------------+---------+-----------+--------------------------------+-----------------------------------+ | IndexLookUp_10 | 3.60 | root | | | | ├─IndexRangeScan_8(Build) | 3.60 | cop[tikv] | table:t1, index:intkey(intkey) | range:[-inf,10), keep order:false | | └─TableRowIDScan_9(Probe) | 3.60 | cop[tikv] | table:t1 | keep order:false | +-------------------------------+---------+-----------+--------------------------------+-----------------------------------+ 3 rows in set (0.00 sec) +-------------------------------+---------+-----------+--------------------------------+-----------------------------------+ | id | estRows | task | access object | operator info | +-------------------------------+---------+-----------+--------------------------------+-----------------------------------+ | IndexLookUp_10 | 5.67 | root | | | | ├─IndexRangeScan_8(Build) | 5.67 | cop[tikv] | table:t1, index:intkey(intkey) | range:[300,310], keep order:false | | └─TableRowIDScan_9(Probe) | 5.67 | cop[tikv] | table:t1 | keep order:false | +-------------------------------+---------+-----------+--------------------------------+-----------------------------------+ 3 rows in set (0.00 sec) +-------------------------------+---------+-----------+--------------------------------+-----------------------------------------------------+ | id | estRows | task | access object | operator info | +-------------------------------+---------+-----------+--------------------------------+-----------------------------------------------------+ | IndexLookUp_10 | 4.00 | root | | | | ├─IndexRangeScan_8(Build) | 4.00 | cop[tikv] | table:t1, index:intkey(intkey) | range:[29,29], [98,98], [123,123], keep order:false | | └─TableRowIDScan_9(Probe) | 4.00 | cop[tikv] | table:t1 | keep order:false | +-------------------------------+---------+-----------+--------------------------------+-----------------------------------------------------+ 3 rows in set (0.00 sec) +-------------------------------+---------+-----------+--------------------------------+----------------------------------+ | id | estRows | task | access object | operator info | +-------------------------------+---------+-----------+--------------------------------+----------------------------------+ | IndexLookUp_10 | 6.00 | root | | | | ├─IndexRangeScan_8(Build) | 6.00 | cop[tikv] | table:t1, index:intkey(intkey) | range:[99,103], keep order:false | | └─TableRowIDScan_9(Probe) | 6.00 | cop[tikv] | table:t1 | keep order:false | +-------------------------------+---------+-----------+--------------------------------+----------------------------------+ 3 rows in set (0.00 sec)

The IndexLookup operator has two child nodes:

  • The ├─IndexRangeScan_8(Build) operator performs a range scan on the intkey index and retrieves the values of the internal RowID (for this table, the primary key).
  • The └─TableRowIDScan_9(Probe) operator then retrieves the full row from the table data.

Because an IndexLookup task requires two steps, the SQL Optimizer might choose the TableFullScan operator based on statistics in scenarios where a large number of rows match. In the following example, a large number of rows match the condition of intkey > 100, and a TableFullScan is chosen:

EXPLAIN SELECT * FROM t1 WHERE intkey > 100;
+-------------------------+---------+-----------+---------------+-------------------------+ | id | estRows | task | access object | operator info | +-------------------------+---------+-----------+---------------+-------------------------+ | TableReader_7 | 898.50 | root | | data:Selection_6 | | └─Selection_6 | 898.50 | cop[tikv] | | gt(test.t1.intkey, 100) | | └─TableFullScan_5 | 1010.00 | cop[tikv] | table:t1 | keep order:false | +-------------------------+---------+-----------+---------------+-------------------------+ 3 rows in set (0.00 sec)

The IndexLookup operator can also be used to efficiently optimize LIMIT on an indexed column:

EXPLAIN SELECT * FROM t1 ORDER BY intkey DESC LIMIT 10;
+--------------------------------+---------+-----------+--------------------------------+------------------------------------+ | id | estRows | task | access object | operator info | +--------------------------------+---------+-----------+--------------------------------+------------------------------------+ | IndexLookUp_21 | 10.00 | root | | limit embedded(offset:0, count:10) | | ├─Limit_20(Build) | 10.00 | cop[tikv] | | offset:0, count:10 | | │ └─IndexFullScan_18 | 10.00 | cop[tikv] | table:t1, index:intkey(intkey) | keep order:true, desc | | └─TableRowIDScan_19(Probe) | 10.00 | cop[tikv] | table:t1 | keep order:false, stats:pseudo | +--------------------------------+---------+-----------+--------------------------------+------------------------------------+ 4 rows in set (0.00 sec)

In the above example, the last 20 rows are read from the index intkey. These RowID values are then retrieved from the table data.

IndexReader

TiDB supports the covering index optimization. If all rows can be retrieved from an index, TiDB will skip the second step that is usually required in an IndexLookup. Consider the following two examples:

EXPLAIN SELECT * FROM t1 WHERE intkey = 123; EXPLAIN SELECT id FROM t1 WHERE intkey = 123;
+-------------------------------+---------+-----------+--------------------------------+-----------------------------------+ | id | estRows | task | access object | operator info | +-------------------------------+---------+-----------+--------------------------------+-----------------------------------+ | IndexLookUp_10 | 1.00 | root | | | | ├─IndexRangeScan_8(Build) | 1.00 | cop[tikv] | table:t1, index:intkey(intkey) | range:[123,123], keep order:false | | └─TableRowIDScan_9(Probe) | 1.00 | cop[tikv] | table:t1 | keep order:false | +-------------------------------+---------+-----------+--------------------------------+-----------------------------------+ 3 rows in set (0.00 sec) +--------------------------+---------+-----------+--------------------------------+-----------------------------------+ | id | estRows | task | access object | operator info | +--------------------------+---------+-----------+--------------------------------+-----------------------------------+ | Projection_4 | 1.00 | root | | test.t1.id | | └─IndexReader_6 | 1.00 | root | | index:IndexRangeScan_5 | | └─IndexRangeScan_5 | 1.00 | cop[tikv] | table:t1, index:intkey(intkey) | range:[123,123], keep order:false | +--------------------------+---------+-----------+--------------------------------+-----------------------------------+ 3 rows in set (0.00 sec)

Because id is also the internal RowID, it is stored in the intkey index. After using the intkey index as part of └─IndexRangeScan_5, the value of the RowID can be returned directly.

Point_Get and Batch_Point_Get

TiDB uses the Point_Get or Batch_Point_Get operator when retrieving data directly from a primary key or unique key. These operators are more efficient than IndexLookup. For example:

EXPLAIN SELECT * FROM t1 WHERE id = 1234; EXPLAIN SELECT * FROM t1 WHERE id IN (1234,123); ALTER TABLE t1 ADD unique_key INT; UPDATE t1 SET unique_key = id; ALTER TABLE t1 ADD UNIQUE KEY (unique_key); EXPLAIN SELECT * FROM t1 WHERE unique_key = 1234; EXPLAIN SELECT * FROM t1 WHERE unique_key IN (1234, 123);
+-------------+---------+------+---------------+---------------+ | id | estRows | task | access object | operator info | +-------------+---------+------+---------------+---------------+ | Point_Get_1 | 1.00 | root | table:t1 | handle:1234 | +-------------+---------+------+---------------+---------------+ 1 row in set (0.00 sec) +-------------------+---------+------+---------------+-------------------------------------------------+ | id | estRows | task | access object | operator info | +-------------------+---------+------+---------------+-------------------------------------------------+ | Batch_Point_Get_1 | 2.00 | root | table:t1 | handle:[1234 123], keep order:false, desc:false | +-------------------+---------+------+---------------+-------------------------------------------------+ 1 row in set (0.00 sec) Query OK, 0 rows affected (0.27 sec) Query OK, 1010 rows affected (0.06 sec) Rows matched: 1010 Changed: 1010 Warnings: 0 Query OK, 0 rows affected (0.37 sec) +-------------+---------+------+----------------------------------------+---------------+ | id | estRows | task | access object | operator info | +-------------+---------+------+----------------------------------------+---------------+ | Point_Get_1 | 1.00 | root | table:t1, index:unique_key(unique_key) | | +-------------+---------+------+----------------------------------------+---------------+ 1 row in set (0.00 sec) +-------------------+---------+------+----------------------------------------+------------------------------+ | id | estRows | task | access object | operator info | +-------------------+---------+------+----------------------------------------+------------------------------+ | Batch_Point_Get_1 | 2.00 | root | table:t1, index:unique_key(unique_key) | keep order:false, desc:false | +-------------------+---------+------+----------------------------------------+------------------------------+ 1 row in set (0.00 sec)

IndexFullScan

Because indexes are ordered, the IndexFullScan operator can be used to optimize common queries such as the MIN or MAX values for an indexed value:

EXPLAIN SELECT MIN(intkey) FROM t1; EXPLAIN SELECT MAX(intkey) FROM t1;
+------------------------------+---------+-----------+--------------------------------+-------------------------------------+ | id | estRows | task | access object | operator info | +------------------------------+---------+-----------+--------------------------------+-------------------------------------+ | StreamAgg_12 | 1.00 | root | | funcs:min(test.t1.intkey)->Column#4 | | └─Limit_16 | 1.00 | root | | offset:0, count:1 | | └─IndexReader_29 | 1.00 | root | | index:Limit_28 | | └─Limit_28 | 1.00 | cop[tikv] | | offset:0, count:1 | | └─IndexFullScan_27 | 1.00 | cop[tikv] | table:t1, index:intkey(intkey) | keep order:true | +------------------------------+---------+-----------+--------------------------------+-------------------------------------+ 5 rows in set (0.00 sec) +------------------------------+---------+-----------+--------------------------------+-------------------------------------+ | id | estRows | task | access object | operator info | +------------------------------+---------+-----------+--------------------------------+-------------------------------------+ | StreamAgg_12 | 1.00 | root | | funcs:max(test.t1.intkey)->Column#4 | | └─Limit_16 | 1.00 | root | | offset:0, count:1 | | └─IndexReader_29 | 1.00 | root | | index:Limit_28 | | └─Limit_28 | 1.00 | cop[tikv] | | offset:0, count:1 | | └─IndexFullScan_27 | 1.00 | cop[tikv] | table:t1, index:intkey(intkey) | keep order:true, desc | +------------------------------+---------+-----------+--------------------------------+-------------------------------------+ 5 rows in set (0.00 sec)

In the above statements, an IndexFullScan task is performed on each TiKV Region. Despite the name FullScan, only the first row needs to be read (└─Limit_28). Each TiKV Region returns its MIN or MAX value to TiDB, which then performs Stream Aggregation to filter for a single row. Stream Aggregation with the aggregation function MAX or MIN also ensures that NULL is returned if the table is empty.

By contrast, executing the MIN function on an unindexed value will result in TableFullScan. The query will require all rows to be scanned in TiKV, but a TopN calculation is performed to ensure each TiKV Region only returns one row to TiDB. Although TopN prevents excessive rows from being transferred between TiKV and TiDB, this statement is still considered far less efficient than the above example where MIN is able to make use of an index.

EXPLAIN SELECT MIN(pad1) FROM t1;
+--------------------------------+---------+-----------+---------------+-----------------------------------+ | id | estRows | task | access object | operator info | +--------------------------------+---------+-----------+---------------+-----------------------------------+ | StreamAgg_13 | 1.00 | root | | funcs:min(test.t1.pad1)->Column#4 | | └─TopN_14 | 1.00 | root | | test.t1.pad1, offset:0, count:1 | | └─TableReader_23 | 1.00 | root | | data:TopN_22 | | └─TopN_22 | 1.00 | cop[tikv] | | test.t1.pad1, offset:0, count:1 | | └─Selection_21 | 1008.99 | cop[tikv] | | not(isnull(test.t1.pad1)) | | └─TableFullScan_20 | 1010.00 | cop[tikv] | table:t1 | keep order:false | +--------------------------------+---------+-----------+---------------+-----------------------------------+ 6 rows in set (0.00 sec)

The following statements will use the IndexFullScan operator to scan every row in the index:

EXPLAIN SELECT SUM(intkey) FROM t1; EXPLAIN SELECT AVG(intkey) FROM t1;
+----------------------------+---------+-----------+--------------------------------+-------------------------------------+ | id | estRows | task | access object | operator info | +----------------------------+---------+-----------+--------------------------------+-------------------------------------+ | StreamAgg_20 | 1.00 | root | | funcs:sum(Column#6)->Column#4 | | └─IndexReader_21 | 1.00 | root | | index:StreamAgg_8 | | └─StreamAgg_8 | 1.00 | cop[tikv] | | funcs:sum(test.t1.intkey)->Column#6 | | └─IndexFullScan_19 | 1010.00 | cop[tikv] | table:t1, index:intkey(intkey) | keep order:false | +----------------------------+---------+-----------+--------------------------------+-------------------------------------+ 4 rows in set (0.00 sec) +----------------------------+---------+-----------+--------------------------------+----------------------------------------------------------------------------+ | id | estRows | task | access object | operator info | +----------------------------+---------+-----------+--------------------------------+----------------------------------------------------------------------------+ | StreamAgg_20 | 1.00 | root | | funcs:avg(Column#7, Column#8)->Column#4 | | └─IndexReader_21 | 1.00 | root | | index:StreamAgg_8 | | └─StreamAgg_8 | 1.00 | cop[tikv] | | funcs:count(test.t1.intkey)->Column#7, funcs:sum(test.t1.intkey)->Column#8 | | └─IndexFullScan_19 | 1010.00 | cop[tikv] | table:t1, index:intkey(intkey) | keep order:false | +----------------------------+---------+-----------+--------------------------------+----------------------------------------------------------------------------+ 4 rows in set (0.00 sec)

In the above examples, IndexFullScan is more efficient than TableFullScan because the width of the value in the (intkey + RowID) index is less than the width of the full row.

The following statement does not support using an IndexFullScan operator because additional columns are required from the table:

EXPLAIN SELECT AVG(intkey), ANY_VALUE(pad1) FROM t1;
+------------------------------+---------+-----------+---------------+-----------------------------------------------------------------------------------------------------------------------+ | id | estRows | task | access object | operator info | +------------------------------+---------+-----------+---------------+-----------------------------------------------------------------------------------------------------------------------+ | Projection_4 | 1.00 | root | | Column#4, any_value(test.t1.pad1)->Column#5 | | └─StreamAgg_16 | 1.00 | root | | funcs:avg(Column#10, Column#11)->Column#4, funcs:firstrow(Column#12)->test.t1.pad1 | | └─TableReader_17 | 1.00 | root | | data:StreamAgg_8 | | └─StreamAgg_8 | 1.00 | cop[tikv] | | funcs:count(test.t1.intkey)->Column#10, funcs:sum(test.t1.intkey)->Column#11, funcs:firstrow(test.t1.pad1)->Column#12 | | └─TableFullScan_15 | 1010.00 | cop[tikv] | table:t1 | keep order:false | +------------------------------+---------+-----------+---------------+-----------------------------------------------------------------------------------------------------------------------+ 5 rows in set (0.00 sec)

Was this page helpful?

Download PDFRequest docs changesAsk questions on Discord
Playground
New
One-stop & interactive experience of TiDB's capabilities WITHOUT registration.
Products
TiDB
TiDB Dedicated
TiDB Serverless
Pricing
Get Demo
Get Started
© 2024 PingCAP. All Rights Reserved.
Privacy Policy.