Documentation Source Text

Check-in [37f6e9f261]
Login

Many hyperlinks are disabled.
Use anonymous login to enable hyperlinks.

Overview
Comment:Add some more documentation for EXPLAIN QUERY PLAN.
Downloads: Tarball | ZIP archive
Timelines: family | ancestors | descendants | both | trunk
Files: files | file ages | folders
SHA1: 37f6e9f2610ee81a424381a2e3735c0f1f35c4d7
User & Date: dan 2010-11-10 18:43:20.000
Context
2010-11-11
17:47
Add extra documentation for EXPLAIN QUERY PLAN. (check-in: 759dfb93a1 user: dan tags: trunk)
2010-11-10
18:43
Add some more documentation for EXPLAIN QUERY PLAN. (check-in: 37f6e9f261 user: dan tags: trunk)
2010-11-03
01:22
Updates to PRAGMA locking_mode and WAL documentation. (check-in: 8ff1145035 user: drh tags: trunk)
Changes
Unified Diff Ignore Whitespace Patch
Changes to pages/lang.in.
1354
1355
1356
1357
1358
1359
1360
1361
1362
1363
1364
1365
1366
1367
1368
1369
1370
1371
1372



























































































































































































































1373
1374
1375
1376
1377
1378
1379

<p>^An SQL statement can be preceded by the keyword "EXPLAIN" or
by the phrase "EXPLAIN QUERY PLAN".  ^Either modification causes the
SQL statement to behave as a query and to return information about
how the SQL statement would have operated if the EXPLAIN keyword or
phrase had been omitted.</p>

<p>^When the EXPLAIN keyword appears by itself it causes the statement
to behave as a query that returns the sequence of 
[virtual machine instructions] it would have
used to execute the command had the EXPLAIN keyword not been present.
^When the EXPLAIN QUERY PLAN phrase appears, the statement returns
high-level information about what indices would have been used.</p>

<p>The output from EXPLAIN and EXPLAIN QUERY PLAN is intended for
interactive analysis and troubleshooting only.  The details of the 
output format are subject to change from one release of SQLite to the next.
Applications should not use EXPLAIN or EXPLAIN QUERY PLAN since
their exact behavior is undocumented, unspecified, and variable.</p>




























































































































































































































<tcl>
##############################################################################
Section expression expr {*expression {expression syntax}}

BubbleDiagram expr 1
BubbleDiagram literal-value







<
<
<
<
<
<
<




|
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>







1354
1355
1356
1357
1358
1359
1360







1361
1362
1363
1364
1365
1366
1367
1368
1369
1370
1371
1372
1373
1374
1375
1376
1377
1378
1379
1380
1381
1382
1383
1384
1385
1386
1387
1388
1389
1390
1391
1392
1393
1394
1395
1396
1397
1398
1399
1400
1401
1402
1403
1404
1405
1406
1407
1408
1409
1410
1411
1412
1413
1414
1415
1416
1417
1418
1419
1420
1421
1422
1423
1424
1425
1426
1427
1428
1429
1430
1431
1432
1433
1434
1435
1436
1437
1438
1439
1440
1441
1442
1443
1444
1445
1446
1447
1448
1449
1450
1451
1452
1453
1454
1455
1456
1457
1458
1459
1460
1461
1462
1463
1464
1465
1466
1467
1468
1469
1470
1471
1472
1473
1474
1475
1476
1477
1478
1479
1480
1481
1482
1483
1484
1485
1486
1487
1488
1489
1490
1491
1492
1493
1494
1495
1496
1497
1498
1499
1500
1501
1502
1503
1504
1505
1506
1507
1508
1509
1510
1511
1512
1513
1514
1515
1516
1517
1518
1519
1520
1521
1522
1523
1524
1525
1526
1527
1528
1529
1530
1531
1532
1533
1534
1535
1536
1537
1538
1539
1540
1541
1542
1543
1544
1545
1546
1547
1548
1549
1550
1551
1552
1553
1554
1555
1556
1557
1558
1559
1560
1561
1562
1563
1564
1565
1566
1567
1568
1569
1570
1571
1572
1573
1574
1575
1576
1577
1578
1579
1580
1581
1582
1583
1584
1585
1586
1587
1588
1589
1590
1591

<p>^An SQL statement can be preceded by the keyword "EXPLAIN" or
by the phrase "EXPLAIN QUERY PLAN".  ^Either modification causes the
SQL statement to behave as a query and to return information about
how the SQL statement would have operated if the EXPLAIN keyword or
phrase had been omitted.</p>








<p>The output from EXPLAIN and EXPLAIN QUERY PLAN is intended for
interactive analysis and troubleshooting only.  The details of the 
output format are subject to change from one release of SQLite to the next.
Applications should not use EXPLAIN or EXPLAIN QUERY PLAN since
their exact behavior is variable and only partially documented.</p>

<p>^When the EXPLAIN keyword appears by itself it causes the statement
to behave as a query that returns the sequence of 
[virtual machine instructions] it would have used to execute the command had
the EXPLAIN keyword not been present. ^When the EXPLAIN QUERY PLAN phrase
appears, the statement returns high-level information regarding the query
plan that would have been used.

<h3>EXPLAIN QUERY PLAN Details</h3>

<p>An EXPLAIN QUERY PLAN command returns zero or more rows of four columns
each. The column names are "selectid", "order", "from", "detail". Each
of the first three column always contains an integer value. The final
column, "detail", which contains most of the useful information, always
contains a text value.

<p>The EXPLAIN QUERY PLAN clause is most useful when used with a SELECT
statement, but may also be used on other statements that read data
from database tables (e.g. UPDATE, DELETE, INSERT INTO ... SELECT).

<h4>Table and Index Scans</h4>

<p>
  When processing a SELECT (or other) statement, SQLite may retrieve data from
  database tables in a variety of ways. It may scan through all the records in
  a table (a full-table scan), scan a contiguous subset of the records in a
  table based on the rowid index, scan a contiguous subset of the entries in a
  database [CREATE TABLE|index], or use a combination of the above strategies
  in a single scan. The various ways in which SQLite may retrieve data from a
  table or index are described in detail [strategies|here].

<p>
  For each table or index scanned, the output of EXPLAIN QUERY PLAN 
  includes a record for which the value in the "detail" column begins
  with the word "SCAN". Each SCAN record includes the following 
  information:

<ul>
  <li> The name of the table data is read from.
  <li> Whether or not an index or [automatic indexing|automatic index] is used.
  <li> Whether or not the [covering index] optimization applies.
  <li> The selectivity of the subset of records scanned.
  <li> The estimated number of rows that SQLite expects the scan to visit.
</ul>

<p>
  For example, the following EXPLAIN QUERY PLAN command operates on a SELECT
  statement that is implemented by performing a full-table scan on table t1:
<pre>
    sqlite> EXPLAIN QUERY PLAN SELECT a, b FROM t1 WHERE a=1; 
    0|0|0|SCAN TABLE t1 (~1000000 rows)
</pre>

<p>
  SQLite estimates that the full-table scan will visit approximately 
  1,000,000 records. If the query were able to use an index, then the SCAN
  record would include the name of the index and a description of how
  it is used by the query. For example:
<pre>
    sqlite> CREATE INDEX i1 ON t1(a);
    sqlite> EXPLAIN QUERY PLAN SELECT a, b FROM t1 WHERE a=1;
    0|0|0|SCAN TABLE t1 BY INDEX i1 (a=?) (~10 rows)
</pre>

<p>
  The output above shows that in this case, SQLite uses index "i1" to optimize
  a WHERE clause filter of the form (a=?) - in this case "a=1". SQLite 
  estimates that scanning the subset of index entries that match the "a=1"
  filter means scanning through approximately 10 records. In this case it is
  not possible to use index i1 as a [covering index], but if it were, the
  SCAN record would report that as well. For example:
<pre>
    sqlite> CREATE INDEX i2 ON t1(a, b);
    sqlite> EXPLAIN QUERY PLAN SELECT a, b FROM t1 WHERE a=1; 
    0|0|0|SCAN TABLE t1 BY COVERING INDEX i2 (a=?) (~10 rows)
</pre>

<p>
  All joins in SQLite are [join order|implemented using nested scans]. When a
  SELECT query that features a join is analyzed using EXPLAIN QUERY PLAN, one
  SCAN record is output for each nested scan. For example:
<pre>
    sqlite> EXPLAIN QUERY PLAN SELECT t1.*, t2.* FROM t1, t2 WHERE t1.a=1 AND t1.b>2;
    0|0|0|SCAN TABLE t1 BY COVERING INDEX i2 (a=? AND b>?) (~3 rows)
    0|1|1|SCAN TABLE t2 (~1000000 rows)
</pre>

<p>
  The second column of output (column "order") indicates the nesting order. In
  this case, the scan of table t1 using index i2 is the outer loop (order=0)
  and the full-table scan of table t2 (order=1) is the inner loop. The third
  column (column "from"), indicates the position in the FROM clause of the
  SELECT statement that the table associated with each scan occurs in. In the
  case above, table t1 occupies the first position in the FROM clause, so the
  value of column "from" is 0 in the first SCAN record. Table t2 is in the
  second position, so the "from" column for the corresponding SCAN record is
  set to 1. In the following example, the positions of t1 and t2 in the FROM 
  clause of the SELECT are reversed. The query strategy remains the same, but
  the values in the "from" column of the output are adjusted accordingly.
<pre>
    sqlite> EXPLAIN QUERY PLAN SELECT t1.*, t2.* FROM t2, t1 WHERE t1.a=1 AND t1.b>2;
    0|0|1|SCAN TABLE t1 BY COVERING INDEX i2 (a=? AND b>?) (~3 rows)
    0|1|0|SCAN TABLE t2 (~1000000 rows)
</pre>

<p>
  In the example above, SQLite estimates that the outer loop scan will visit
  approximately 3 rows, and the inner loop scan approximately 1,000,000. If
  you observe that SQLite's estimates are wildly inaccurate (and appear to be
  causing it to generate sub-optimal query plans), your queries may benefit
  from running the [ANALYZE] command on the database.

<p>
  If the WHERE clause of a query contains an OR expression, then SQLite might
  use the [or-connected-terms|"OR by union"] strategy (also described 
  [or optimization|here]). In this case there will be two SCAN records, one
  for each index scan, with the same values in both the "order" and "from" 
  columns. For example:
<pre>
    sqlite> CREATE INDEX i3 ON t1(b);
    sqlite> EXPLAIN QUERY PLAN SELECT * FROM t1 WHERE a=1 OR b=2;
    0|0|0|SCAN TABLE t1 BY INDEX i1 (a=?) (~10 rows)
    0|0|0|SCAN TABLE t1 BY INDEX i3 (b=?) (~10 rows)
</pre>

<h4>Temporary Sorting B-Trees</h4>

<p>
  If a SELECT query contains an ORDER BY, GROUP BY or DISTINCT clause, 
  SQLite may need to use a temporary b-tree structure to perform an 
  <a href="http://en.wikipedia.org/wiki/Insertion_sort">insertion sort</a> 
  of the output rows. Or, it may [sorting|use an index]. Using an index is 
  almost always much more efficient than performing an online insertion sort.
  If a temporary b-tree is required, a record is added to the EXPLAIN
  QUERY PLAN output with the "detail" field set to a string value of
  the form "USE TEMP B-TREE FOR xxx", where xxx is one of "ORDER BY",
  "GROUP BY" or "DISTINCT". For example:

<pre>
    sqlite> EXPLAIN QUERY PLAN SELECT c, d FROM t2 ORDER BY c; 
    0|0|0|SCAN TABLE t2 (~1000000 rows)
    0|0|0|USE TEMP B-TREE FOR ORDER BY
</pre>

<p>
  In this case using the temporary b-tree can be avoided by creating an index
  on t2(c), as follows:

<pre>
    sqlite> CREATE INDEX i4 ON t2(c);
    sqlite> EXPLAIN QUERY PLAN SELECT c, d FROM t2 ORDER BY c; 
    0|0|0|SCAN TABLE t2 BY INDEX i4 (~1000000 rows)
</pre>

<h4>Subqueries</h4>

<p>
  In all the examples above, the first column (column "selectid") is always
  set to 0. If a query contains sub-selects, either as part of the FROM
  clause or as part of SQL expressions, then the output of EXPLAIN QUERY
  PLAN also includes a report for each sub-select. Each sub-select is assigned
  a distinct, non-zero "selectid" value. The top-level SELECT statement is
  always assigned the selectid value 0. For example:

<pre>
    sqlite> EXPLAIN QUERY PLAN SELECT (SELECT b FROM t1 WHERE a=0), (SELECT a FROM t1 WHERE b=t2.c) FROM t2;
    0|0|0|SCAN TABLE t2 (~1000000 rows)
    0|0|0|EXECUTE SCALAR SUBQUERY 1
    1|0|0|SCAN TABLE t1 BY COVERING INDEX i2 (a=?) (~10 rows)
    0|0|0|EXECUTE CORRELATED SCALAR SUBQUERY 2
    2|0|0|SCAN TABLE t1 BY INDEX i3 (b=?) (~10 rows)
</pre>

<p>
  The example above contains a pair of scalar subqueries assigned selectid 
  values 1 and 2. As well as a SCAN record, there are also 2 "EXECUTE" 
  records associated with the top level subquery (selectid 0), indicating
  that subqueries 1 and 2 are executed by the top level query in a scalar
  context. The CORRELATED qualifier present in the EXECUTE record associated
  with scalar subquery 2 indicates that the query must be run separately
  for each row visited by the top level query. Its absence in the record
  associated with subquery 1 means that the subquery is only run once and
  the result cached. In other words, subquery 2 may be more performance
  critical, as it may be run many times whereas subquery 1 is only ever run
  once.

<p>
  Unless the [flattening optimization] is applied, if a subquery appears in
  the FROM clause of a SELECT statement, SQLite executes the subquery and
  stores the results in a temporary table. It then uses the contents of the 
  temporary table in place of the subquery to execute the parent query. This
  is shown in the output of EXPLAIN QUERY PLAN by substituting a 
  "SCAN SUBQUERY" record for the "SCAN TABLE" record that normally appears
  for each element in the FROM clause. For example:

<pre>
    sqlite> EXPLAIN QUERY PLAN SELECT count(*) FROM (SELECT max(b) AS x FROM t1 GROUP BY a) GROUP BY x;
    1|0|0|SCAN TABLE t1 BY COVERING INDEX i2 (~1000000 rows)
    0|0|0|SCAN SUBQUERY 1 (~1000000 rows)
    0|0|0|USE TEMP B-TREE FOR GROUP BY
</pre>

<p>
  If the [flattening optimization] is used on a subquery in the FROM clause
  of a SELECT statement, then the output of EXPLAIN QUERY PLAN reflects this.
  For example, in the following there is no "SCAN SUBQUERY" record even though
  there is a subquery in the FROM clause of the top level SELECT. Instead, since
  the flattening optimization does apply in this case, the EXPLAIN QUERY PLAN
  report shows that the top level query is implemented using a nested loop join
  of tables t1 and t2.

<pre>
    sqlite> EXPLAIN QUERY PLAN SELECT * FROM (SELECT * FROM t2 WHERE c=1), t1;
    0|0|0|SCAN TABLE t2 BY INDEX i4 (c=?) (~10 rows)
    0|1|1|SCAN TABLE t1 (~1000000 rows)
</pre>




<tcl>
##############################################################################
Section expression expr {*expression {expression syntax}}

BubbleDiagram expr 1
BubbleDiagram literal-value
Changes to pages/optoverview.in.
217
218
219
220
221
222
223

224
225
226
227
228
229
230
  input rows.
  ^Thus if the BETWEEN term is not used as an index constraint and
  instead must be used to test input rows, the <i>expr1</i> expression is
  only evaluated once.
}

HEADING 1 {OR optimizations} or_opt


PARAGRAPH {
  WHERE clause constraints that are connected by OR instead of AND are
  handled in one of two way.
  ^(If a term consists of multiple subterms containing a common column
  name and separated by OR, like this:
}







>







217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
  input rows.
  ^Thus if the BETWEEN term is not used as an index constraint and
  instead must be used to test input rows, the <i>expr1</i> expression is
  only evaluated once.
}

HEADING 1 {OR optimizations} or_opt
hd_keywords {or optimization}

PARAGRAPH {
  WHERE clause constraints that are connected by OR instead of AND are
  handled in one of two way.
  ^(If a term consists of multiple subterms containing a common column
  name and separated by OR, like this:
}
463
464
465
466
467
468
469

470
471
472
473
474
475
476
  in the WHERE clause.  ^The net effect is that putting the ON or USING
  clause expressions for a LEFT JOIN in the WHERE clause effectively converts
  the query to an
  ordinary INNER JOIN - albeit an inner join that runs more slowly.
}

HEADING 2 {Order of tables in a join} table_order


PARAGRAPH {
  The current implementation of 
  SQLite uses only loop joins.  That is to say, joins are implemented as
  nested loops.
}
PARAGRAPH {







>







464
465
466
467
468
469
470
471
472
473
474
475
476
477
478
  in the WHERE clause.  ^The net effect is that putting the ON or USING
  clause expressions for a LEFT JOIN in the WHERE clause effectively converts
  the query to an
  ordinary INNER JOIN - albeit an inner join that runs more slowly.
}

HEADING 2 {Order of tables in a join} table_order
hd_keywords {join order}

PARAGRAPH {
  The current implementation of 
  SQLite uses only loop joins.  That is to say, joins are implemented as
  nested loops.
}
PARAGRAPH {
818
819
820
821
822
823
824

825
826
827
828
829
830
831
  constraints or satisfying an ORDER BY clause, SQLite does the same
  work analysis described above
  and chooses the index that it believes will result in the fastest answer.

}

HEADING 1 {Subquery flattening} flattening


PARAGRAPH {
  When a subquery occurs in the FROM clause of a SELECT, the simplest
  behavior is to evaluate the subquery into a transient table, then run
  the outer SELECT against the transient table.  But such a plan
  can be suboptimal since the transient table will not have any indices
  and the outer query (which is likely a join) will be forced to do a







>







820
821
822
823
824
825
826
827
828
829
830
831
832
833
834
  constraints or satisfying an ORDER BY clause, SQLite does the same
  work analysis described above
  and chooses the index that it believes will result in the fastest answer.

}

HEADING 1 {Subquery flattening} flattening
hd_keywords {flattening optimization}

PARAGRAPH {
  When a subquery occurs in the FROM clause of a SELECT, the simplest
  behavior is to evaluate the subquery into a transient table, then run
  the outer SELECT against the transient table.  But such a plan
  can be suboptimal since the transient table will not have any indices
  and the outer query (which is likely a join) will be forced to do a
Changes to pages/queryplanner.in.
41
42
43
44
45
46
47

48
49
50
51
52
53
54
This document is intended to provide programmers who are new to SQL
with background information to help them understand
what is going on behind the scenes with SQLite, which in turn should make
it easier for programmers to create the indices that will help the SQLite
query planner to pick the best plans.
</p>


<h2>1.0 Searching</h2>

<h3>1.1 Tables Without Indices</h3>

<p>
Every table in SQLite consists of zero or more rows with a unique integer
key (the [rowid] or [INTEGER PRIMARY KEY]) followed by content.  The rows







>







41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
This document is intended to provide programmers who are new to SQL
with background information to help them understand
what is going on behind the scenes with SQLite, which in turn should make
it easier for programmers to create the indices that will help the SQLite
query planner to pick the best plans.
</p>

<tcl>hd_fragment searching strategies</tcl>
<h2>1.0 Searching</h2>

<h3>1.1 Tables Without Indices</h3>

<p>
Every table in SQLite consists of zero or more rows with a unique integer
key (the [rowid] or [INTEGER PRIMARY KEY]) followed by content.  The rows
398
399
400
401
402
403
404

405
406
407
408
409
410
411
the speed).  But on the other hand, it is also just a refinement;
A two-fold performance increase is not nearly as dramatic as the
one-million-fold increase seen when the table was first indexed.
And for most queries, the difference between 1 microsecond and
2 microseconds is unlikely to be noticed.
</p>


<h3>1.8 OR-Connected Terms In The WHERE Clause</h3>

<p>
Multi-column indices only work if the constraint terms in the WHERE
clause of the query are connected by AND.
So Idx3 and Idx4 are helpful when the search is for items that
are both Oranges and grown in California, but neither index would







>







399
400
401
402
403
404
405
406
407
408
409
410
411
412
413
the speed).  But on the other hand, it is also just a refinement;
A two-fold performance increase is not nearly as dramatic as the
one-million-fold increase seen when the table was first indexed.
And for most queries, the difference between 1 microsecond and
2 microseconds is unlikely to be noticed.
</p>

<tcl>hd_fragment or_in_where or-connected-terms</tcl>
<h3>1.8 OR-Connected Terms In The WHERE Clause</h3>

<p>
Multi-column indices only work if the constraint terms in the WHERE
clause of the query are connected by AND.
So Idx3 and Idx4 are helpful when the search is for items that
are both Oranges and grown in California, but neither index would