Skip to content

Commit

Permalink
sql tuning: add EXPLAIN views (#3862)
Browse files Browse the repository at this point in the history
* sql tuning: add EXPLAIN views

* Update explain-views.md

Co-authored-by: Feng Liyuan <[email protected]>

* Update explain-views.md

Co-authored-by: TomShawn <[email protected]>

* Update explain-views.md

Co-authored-by: TomShawn <[email protected]>

* Update explain-views.md

Co-authored-by: TomShawn <[email protected]>

* Update explain-views.md

Co-authored-by: TomShawn <[email protected]>

* Update explain-views.md

Co-authored-by: TomShawn <[email protected]>

* Update explain-views.md

Co-authored-by: TomShawn <[email protected]>

* Update explain-views.md

* Apply suggestions from code review

Co-authored-by: Feng Liyuan <[email protected]>
Co-authored-by: TomShawn <[email protected]>
  • Loading branch information
3 people authored Sep 17, 2020
1 parent 4f89eb8 commit 6ad9bb4
Showing 1 changed file with 109 additions and 0 deletions.
109 changes: 109 additions & 0 deletions explain-views.md
Original file line number Diff line number Diff line change
@@ -0,0 +1,109 @@
---
title: EXPLAIN Statements Using Views
summary: Learn about the execution plan information returned by the `EXPLAIN` statement in TiDB.
---

# EXPLAIN Statements Using Views

`EXPLAIN` displays the tables and indexes that a [view](/views.md) references, not the name of the view itself. This is because views are only virtual tables and do not store any data themselves. The definition of the view and the rest of the statement are merged together during SQL optimization.

From the [bikeshare example database](/import-example-data.md), you can see that the following two queries are executed in a similar manner:

{{< copyable "sql" >}}

```sql
ALTER TABLE trips ADD INDEX (duration);
CREATE OR REPLACE VIEW long_trips AS SELECT * FROM trips WHERE duration > 3600;
EXPLAIN SELECT * FROM long_trips;
EXPLAIN SELECT * FROM trips WHERE duration > 3600;
```

```sql
Query OK, 0 rows affected (2 min 10.11 sec)

Query OK, 0 rows affected (0.13 sec)

+--------------------------------+------------+-----------+---------------------------------------+-------------------------------------+
| id | estRows | task | access object | operator info |
+--------------------------------+------------+-----------+---------------------------------------+-------------------------------------+
| IndexLookUp_12 | 6372547.67 | root | | |
| ├─IndexRangeScan_10(Build) | 6372547.67 | cop[tikv] | table:trips, index:duration(duration) | range:(3600,+inf], keep order:false |
| └─TableRowIDScan_11(Probe) | 6372547.67 | cop[tikv] | table:trips | keep order:false |
+--------------------------------+------------+-----------+---------------------------------------+-------------------------------------+
3 rows in set (0.00 sec)

+-------------------------------+-----------+-----------+---------------------------------------+-------------------------------------+
| id | estRows | task | access object | operator info |
+-------------------------------+-----------+-----------+---------------------------------------+-------------------------------------+
| IndexLookUp_10 | 833219.37 | root | | |
| ├─IndexRangeScan_8(Build) | 833219.37 | cop[tikv] | table:trips, index:duration(duration) | range:(3600,+inf], keep order:false |
| └─TableRowIDScan_9(Probe) | 833219.37 | cop[tikv] | table:trips | keep order:false |
+-------------------------------+-----------+-----------+---------------------------------------+-------------------------------------+
3 rows in set (0.00 sec)
```

Similarly, predicates from the view are pushed down to the base table:

{{< copyable "sql" >}}

```sql
EXPLAIN SELECT * FROM long_trips WHERE bike_number = 'W00950';
EXPLAIN SELECT * FROM trips WHERE bike_number = 'W00950';
```

```sql
+--------------------------------+---------+-----------+---------------------------------------+---------------------------------------------------+
| id | estRows | task | access object | operator info |
+--------------------------------+---------+-----------+---------------------------------------+---------------------------------------------------+
| IndexLookUp_14 | 3.33 | root | | |
| ├─IndexRangeScan_11(Build) | 3333.33 | cop[tikv] | table:trips, index:duration(duration) | range:(3600,+inf], keep order:false, stats:pseudo |
| └─Selection_13(Probe) | 3.33 | cop[tikv] | | eq(bikeshare.trips.bike_number, "W00950") |
| └─TableRowIDScan_12 | 3333.33 | cop[tikv] | table:trips | keep order:false, stats:pseudo |
+--------------------------------+---------+-----------+---------------------------------------+---------------------------------------------------+
4 rows in set (0.00 sec)

+-------------------------+-------------+-----------+---------------+-------------------------------------------+
| id | estRows | task | access object | operator info |
+-------------------------+-------------+-----------+---------------+-------------------------------------------+
| TableReader_7 | 43.00 | root | | data:Selection_6 |
| └─Selection_6 | 43.00 | cop[tikv] | | eq(bikeshare.trips.bike_number, "W00950") |
| └─TableFullScan_5 | 19117643.00 | cop[tikv] | table:trips | keep order:false |
+-------------------------+-------------+-----------+---------------+-------------------------------------------+
3 rows in set (0.00 sec)
```

In the first statement above, you can see that the index is used to satisfy the view definition, and then the `bike_number = 'W00950'` is applied when TiDB reads the table row. In the second statement, there are no indexes to satisfy the statement, and a `TableFullScan` is used.

TiDB makes use of indexes that satisfy both the view definition and the statement itself. Consider the following composite index:

{{< copyable "sql" >}}

```sql
ALTER TABLE trips ADD INDEX (bike_number, duration);
EXPLAIN SELECT * FROM long_trips WHERE bike_number = 'W00950';
EXPLAIN SELECT * FROM trips WHERE bike_number = 'W00950';
```

```sql
Query OK, 0 rows affected (2 min 31.20 sec)

+--------------------------------+----------+-----------+-------------------------------------------------------+-------------------------------------------------------+
| id | estRows | task | access object | operator info |
+--------------------------------+----------+-----------+-------------------------------------------------------+-------------------------------------------------------+
| IndexLookUp_13 | 63725.48 | root | | |
| ├─IndexRangeScan_11(Build) | 63725.48 | cop[tikv] | table:trips, index:bike_number(bike_number, duration) | range:("W00950" 3600,"W00950" +inf], keep order:false |
| └─TableRowIDScan_12(Probe) | 63725.48 | cop[tikv] | table:trips | keep order:false |
+--------------------------------+----------+-----------+-------------------------------------------------------+-------------------------------------------------------+
3 rows in set (0.00 sec)

+-------------------------------+----------+-----------+-------------------------------------------------------+---------------------------------------------+
| id | estRows | task | access object | operator info |
+-------------------------------+----------+-----------+-------------------------------------------------------+---------------------------------------------+
| IndexLookUp_10 | 19117.64 | root | | |
| ├─IndexRangeScan_8(Build) | 19117.64 | cop[tikv] | table:trips, index:bike_number(bike_number, duration) | range:["W00950","W00950"], keep order:false |
| └─TableRowIDScan_9(Probe) | 19117.64 | cop[tikv] | table:trips | keep order:false |
+-------------------------------+----------+-----------+-------------------------------------------------------+---------------------------------------------+
3 rows in set (0.00 sec)
```

In the first statement, TiDB is able to use both parts of the composite index `(bike_number, duration)`. In the second statement, only the first part which is `bike_number` of the index `(bike_number, duration)` is used.

0 comments on commit 6ad9bb4

Please sign in to comment.