The TABLE SCAN operator provides an interface between the storage and SQL layers and shows which index is selected by the optimizer for data access.
In OceanBase Database V4.1.0, the table access logic for normal indexes and global indexes are encapsulated in the TABLE SCAN operator. When the execution plan is displayed, is_index_back indicates whether table access by index primary key is required by the operator, and is_global_index indicates whether the operator scans a global index.
Example: an execution plan that contains a TABLE SCAN operator
Q1:
obclient> CREATE TABLE t1(c1 INT PRIMARY KEY, c2 INT, c3 INT, c4 INT);
obclient> CREATE INDEX e1 ON t1(c1,c2);
obclient> EXPLAIN SELECT * FROM t1 WHERE c1 = 1;
+--------------------------------------------------------------------------+
| Query Plan |
+--------------------------------------------------------------------------+
| ========================================= |
| |ID|OPERATOR |NAME|EST.ROWS|EST.TIME(us)| |
| ----------------------------------------- |
| |0 |TABLE GET|T1 |1 |3 | |
| ========================================= |
| Outputs & filters: |
| ------------------------------------- |
| 0 - output([T1.C1], [T1.C2], [T1.C3], [T1.C4]), filter(nil), rowset=16 |
| access([T1.C1], [T1.C2], [T1.C3], [T1.C4]), partitions(p0) |
| is_index_back=false, is_global_index=false, |
| range_key([T1.C1]), range[1 ; 1], |
| range_cond([T1.C1 = 1]) |
+--------------------------------------------------------------------------+
Q2:
obclient> EXPLAIN SELECT * FROM t1 WHERE c2 < 1 AND c3 < 1 AND c4 < 1;
+------------------------------------------------------------------------------------------------------------+
| Query Plan |
+------------------------------------------------------------------------------------------------------------+
| =============================================== |
| |ID|OPERATOR |NAME|EST.ROWS|EST.TIME(us)| |
| ----------------------------------------------- |
| |0 |TABLE FULL SCAN|T1 |1 |4 | |
| =============================================== |
| Outputs & filters: |
| ------------------------------------- |
| 0 - output([T1.C1], [T1.C2], [T1.C3], [T1.C4]), filter([T1.C2 < 1], [T1.C3 < 1], [T1.C4 < 1]), rowset=16 |
| access([T1.C1], [T1.C2], [T1.C3], [T1.C4]), partitions(p0) |
| is_index_back=false, is_global_index=false, filter_before_indexback[false,false,false], |
| range_key([T1.C1]), range(MIN ; MAX)always true |
+------------------------------------------------------------------------------------------------------------+
Q3:
obclient> CREATE TABLE t2(c1 INT PRIMARY KEY, c2 INT, c3 INT) PARTITION BY HASH(c1) PARTITIONS 4;
obclient> CREATE INDEX i2 ON t2(c2) GLOBAL;
obclient> EXPLAIN SELECT * FROM t2 WHERE c2 = 1;
+-----------------------------------------------------------------+
| Query Plan |
+-----------------------------------------------------------------+
| ============================================================== |
| |ID|OPERATOR |NAME |EST.ROWS|EST.TIME(us)| |
| -------------------------------------------------------------- |
| |0 |DISTRIBUTED TABLE RANGE SCAN|T2(I2)|1 |30 | |
| ============================================================== |
| Outputs & filters: |
| ------------------------------------- |
| 0 - output([T2.C1], [T2.C2], [T2.C3]), filter(nil), rowset=16 |
| access([T2.C1], [T2.C2], [T2.C3]), partitions(p0) |
| is_index_back=true, is_global_index=true, |
| range_key([T2.C2], [T2.C1]), range(1,MIN ; 1,MAX), |
| range_cond([T2.C2 = 1]) |
+-----------------------------------------------------------------+
Q4:
obclient> CREATE TABLE t3(pk INT, c1 INT, c2 INT, PRIMARY KEY(pk));
obclient> INSERT INTO t3 (pk,c1,c2) SELECT LEVEL, MOD(LEVEL,3), LEVEL FROM DUAL CONNECT BY LEVEL <= 10000;
obclient> CREATE INDEX i1 ON t3(c1,c2);
obclient> EXPLAIN SELECT /*+ INDEX_SS(t3 i1) */ * FROM t3 WHERE c2 = 1;
+-----------------------------------------------------------------------------------------+
| Query Plan |
+-----------------------------------------------------------------------------------------+
| ================================================= |
| |ID|OPERATOR |NAME |EST.ROWS|EST.TIME(us)| |
| ------------------------------------------------- |
| |0 |TABLE SKIP SCAN|T3(I1)|1 |17 | |
| ================================================= |
| Outputs & filters: |
| ------------------------------------- |
| 0 - output([T3.PK], [T3.C1], [T3.C2]), filter([T3.C2 = 1]), rowset=16 |
| access([T3.PK], [T3.C2], [T3.C1]), partitions(p0) |
| is_index_back=false, is_global_index=false, filter_before_indexback[false], |
| range_key([T3.C1], [T3.C2], [T3.PK]), range(MIN,MIN,MIN ; MAX,MAX,MAX)always true |
| prefix_columns_cnt = 1 , skip_scan_range(1,MIN ; 1,MAX) |
+-----------------------------------------------------------------------------------------+
In the preceding example, the Outputs & filters section shows in detail the output information of the TABLE SCAN operator.
| Field | Description |
|---|---|
| operator | The TABLE SCAN operator has three forms: TABLE SCAN, TABLE GET, and Table SKIP SCAN.
|
| name | The index selected for accessing data. The name of the selected index follows the table name. The absence of the index name means that the primary table is scanned. In OceanBase Database, the primary table has the same structure as the index, and the primary table is an index. |
| output | The output columns of the operator. |
| filter | The filter predicates of the operator. In this example, filter is set to nil because no filter condition is configured for the TABLE GET operator in query Q1. |
| partitions | The partitions to be scanned in the query. |
| is_index_back | Indicates whether table access by index primary key is required by the operator. In query Q1, the primary table is selected. Therefore, table access by index primary key is not required. In query Q2, where the indexed columns are c2, c3, and c1, table access by index primary key is required because the query needs to return column c4. |
| is_global_index | Indicates whether the operator performs a global index scan. For example, in query Q2, a normal index is used. Therefore, is_global_index is false. In query Q3, index i2 of table t2 is used, and index i2 is a global index. Therefore, is_global_index is true. |
| filter_before_indexback | Corresponds to each filter and indicates whether the filter directly applies to the index or after the table access by index primary key operation. For example, in query Q2, filter c3 < 1 can be directly applied to the index, which reduces the number of table access by index primary key operations. However, filter c4 < 1 can be applied only after column c4 is fetched through table access. |
| range_key/range/range_cond |
|
| prefix_columns_cnt | The number of prefix columns for the INDEX SKIP SCAN operator. |
| skip_scan_range | The scan range extracted by the INDEX SKIP SCAN operator from the suffix columns. |
In query Q4, the Table SKIP SCAN operator can accelerate scanning by using existing indexes in specific circumstances. OceanBase Database uses the Table SKIP SCAN operator in the following circumstances:
- Statistics have been collected from the table.
- The query conditions include the suffix columns of a composite index and the suffix columns are not the leftmost prefixes of other indexes.
- The optimizer finds that a table skip scan has lower costs than a full-table scan does.