Many hyperlinks are disabled.
Use anonymous login
to enable hyperlinks.
Overview
Comment: | Add evidence marks to examples on lang_explain.html. |
---|---|
Downloads: | Tarball | ZIP archive |
Timelines: | family | ancestors | descendants | both | trunk |
Files: | files | file ages | folders |
SHA1: |
360fe452452b77c8b79ab8229c3784fb |
User & Date: | dan 2010-11-12 17:40:53.000 |
Context
2010-11-13
| ||
17:10 | Update EXPLAIN QUERY PLAN examples to match changes to sqlite. (check-in: 3f8c0a0c1f user: dan tags: trunk) | |
2010-11-12
| ||
17:40 | Add evidence marks to examples on lang_explain.html. (check-in: 360fe45245 user: dan tags: trunk) | |
2010-11-11
| ||
17:47 | Add extra documentation for EXPLAIN QUERY PLAN. (check-in: 759dfb93a1 user: dan tags: trunk) | |
Changes
Changes to pages/lang.in.
︙ | ︙ | |||
1407 1408 1409 1410 1411 1412 1413 | <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: | | | | | | | | | | | | | | | | | | | | | | 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 | <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 (~100000 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 COVERING INDEX i2 (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 |
︙ | ︙ | |||
1554 1555 1556 1557 1558 1559 1560 | 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: | | | | | | | | | | 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 1592 1593 1594 1595 1596 1597 1598 1599 1600 1601 1602 1603 1604 1605 1606 1607 1608 1609 1610 1611 1612 1613 1614 1615 1616 1617 1618 | 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> <h4>Compound Queries</h4> <p> Each component query of a [compound query] (UNION, UNION ALL, EXCEPT or INTERSECT) is assigned its own selectid and reported on separately. A single record is output for the parent (compound query) identifying the operation, and whether or not a temporary b-tree is used to implement it. For example: <pre>^( sqlite> EXPLAIN QUERY PLAN SELECT a FROM t1 UNION SELECT c FROM t2; 1|0|0|SCAN TABLE t1 (~1000000 rows) 2|0|0|SCAN TABLE t2 (~1000000 rows) 0|0|0|COMPOUND SUBQUERIES 1 AND 2 USING TEMP B-TREE (UNION) )^</pre> <p> The "USING TEMP B-TREE" clause in the above output indicates that a temporary b-tree structure is used to implement the UNION of the results of the two sub-selects. If the temporary b-tree were not required, as in the following example, the clause is not present. <pre>^( sqlite> EXPLAIN QUERY PLAN SELECT a FROM t1 EXCEPT SELECT d FROM t2 ORDER BY 1; 1|0|0|SCAN TABLE t1 BY COVERING INDEX i2 (~1000000 rows) 2|0|0|SCAN TABLE t2 (~1000000 rows) 2|0|0|USE TEMP B-TREE FOR ORDER BY 0|0|0|COMPOUND SUBQUERIES 1 AND 2 (EXCEPT) )^</pre> <tcl> ############################################################################## Section expression expr {*expression {expression syntax}} BubbleDiagram expr 1 |
︙ | ︙ |