Many hyperlinks are disabled.
Use anonymous login
to enable hyperlinks.
Overview
Comment: | Add additional requirements marks and reword a few sentences in eqp.html. |
---|---|
Downloads: | Tarball | ZIP archive |
Timelines: | family | ancestors | descendants | both | trunk |
Files: | files | file ages | folders |
SHA1: |
09966391b192893e24643a580c473482 |
User & Date: | drh 2010-11-15 18:43:30.000 |
Context
2010-11-17
| ||
01:32 | Add the sqlite3_stmt_readonly() function to the change log. (check-in: c591c1b79d user: drh tags: trunk) | |
2010-11-15
| ||
18:43 | Add additional requirements marks and reword a few sentences in eqp.html. (check-in: 09966391b1 user: drh tags: trunk) | |
17:35 | Minor fixes for sample code in eqp.in. (check-in: 897bd4f88e user: dan tags: trunk) | |
Changes
Changes to pages/eqp.in.
︙ | ︙ | |||
15 16 17 18 19 20 21 | <p>The [EXPLAIN|EXPLAIN QUERY PLAN] SQL command is used to obtain a high-level description of the strategy or plan that SQLite uses to implement a specific SQL query. Most significantly, it reports on the way in which the query uses database indices. In interpreting and using this information to optimize database schemas and queries, users might find the documents describing how SQLite [indexing|plans] and [optimizer|optimizes] queries useful. | | | | < | > | | | | | | | | > | | | | < | | | > | | 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 35 36 37 38 39 40 41 42 43 44 45 46 47 48 49 50 51 52 53 54 55 56 57 58 59 60 61 62 63 64 65 66 67 68 69 70 71 72 73 74 75 76 77 78 79 80 81 82 83 84 85 86 87 88 89 90 91 92 93 94 95 96 97 98 99 100 101 102 103 104 105 106 107 108 109 110 111 112 113 114 115 116 117 118 119 120 121 122 123 124 125 126 127 128 129 130 131 | <p>The [EXPLAIN|EXPLAIN QUERY PLAN] SQL command is used to obtain a high-level description of the strategy or plan that SQLite uses to implement a specific SQL query. Most significantly, it reports on the way in which the query uses database indices. In interpreting and using this information to optimize database schemas and queries, users might find the documents describing how SQLite [indexing|plans] and [optimizer|optimizes] queries useful. <p>^An EXPLAIN QUERY PLAN command returns zero or more rows of four columns each. ^The column names are "selectid", "order", "from", "detail". ^The first three columns contain an integer value. ^The final column, "detail", contains a text value which carries most of the useful information. <p>^(EXPLAIN QUERY PLAN is most useful on a SELECT statement, but may also be appear with other statements that read data from database tables (e.g. UPDATE, DELETE, INSERT INTO ... SELECT).)^ <h2>Table and Index Scans</h2> <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 read by the query, the output of EXPLAIN QUERY PLAN includes a record for which the value in the "detail" column begins with either "SCAN" or "SEARCH". ^"SCAN" is used for a full-table scan, including cases where SQLite iterates through all records in a table in an order defined by an index. ^"SEARCH" indicates that only a subset of the table rows are visited. ^(Each SCAN or SEARCH 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: ^(<codeblock> sqlite> EXPLAIN QUERY PLAN SELECT a, b FROM t1 WHERE a=1; 0|0|0|SCAN TABLE t1 (~100000 rows) </codeblock>)^ <p> The example above shows SQLite estimating that the full-table scan will visit approximately 1,000,000 records. If the query were able to use an index, then the SCAN/SEARCH record would include the name of the index and, for a SEARCH record, an indication of how the subset of rows visited is identified. For example: ^(<codeblock> sqlite> CREATE INDEX i1 ON t1(a); sqlite> EXPLAIN QUERY PLAN SELECT a, b FROM t1 WHERE a=1; 0|0|0|SEARCH TABLE t1 USING INDEX i1 (a=?) (~10 rows) </codeblock>)^ <p> The previous example, SQLite uses index "i1" to optimize a WHERE clause term of the form (a=?) - in this case "a=1". SQLite estimates that about 10 records will match the "a=1" term. The previous example could not use a [covering index], but the following example can, and that fact is reflected in the output: ^(<codeblock> sqlite> CREATE INDEX i2 ON t1(a, b); sqlite> EXPLAIN QUERY PLAN SELECT a, b FROM t1 WHERE a=1; 0|0|0|SEARCH TABLE t1 USING COVERING INDEX i2 (a=?) (~10 rows) </codeblock>)^ <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 or SEARCH record is output for each nested loop. For example: ^(<codeblock> sqlite> EXPLAIN QUERY PLAN SELECT t1.*, t2.* FROM t1, t2 WHERE t1.a=1 AND t1.b>2; 0|0|0|SEARCH TABLE t1 USING COVERING INDEX i2 (a=? AND b>?) (~3 rows) 0|1|1|SCAN TABLE t2 (~1000000 rows) </codeblock>)^ <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 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. ^(<codeblock> sqlite> EXPLAIN QUERY PLAN SELECT t1.*, t2.* FROM t2, t1 WHERE t1.a=1 AND t1.b>2; 0|0|1|SEARCH TABLE t1 USING COVERING INDEX i2 (a=? AND b>?) (~3 rows) 0|1|0|SCAN TABLE t2 (~1000000 rows) </codeblock>)^ <p> In the example above, SQLite estimates that the outer loop scan will visit approximately 3 rows, and that the inner loop will visit 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 |
︙ | ︙ | |||
138 139 140 141 142 143 144 | 0|0|0|SEARCH TABLE t1 USING INDEX i3 (b=?) (~10 rows) </codeblock>)^ <h2>Temporary Sorting B-Trees</h2> <p> If a SELECT query contains an ORDER BY, GROUP BY or DISTINCT clause, | | < | | | 139 140 141 142 143 144 145 146 147 148 149 150 151 152 153 154 155 | 0|0|0|SEARCH TABLE t1 USING INDEX i3 (b=?) (~10 rows) </codeblock>)^ <h2>Temporary Sorting B-Trees</h2> <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 sort the output rows. Or, it might [sorting|use an index]. Using an index is almost always much more efficient than performing a 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: ^(<codeblock> sqlite> EXPLAIN QUERY PLAN SELECT c, d FROM t2 ORDER BY c; |
︙ | ︙ | |||
167 168 169 170 171 172 173 | 0|0|0|SCAN TABLE t2 USING INDEX i4 (~1000000 rows) </codeblock>)^ <h2>Subqueries</h2> <p> In all the examples above, the first column (column "selectid") is always | | | | | 167 168 169 170 171 172 173 174 175 176 177 178 179 180 181 182 183 184 | 0|0|0|SCAN TABLE t2 USING INDEX i4 (~1000000 rows) </codeblock>)^ <h2>Subqueries</h2> <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: ^(<codeblock> 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|SEARCH TABLE t1 USING COVERING INDEX i2 (a=?) (~10 rows) |
︙ | ︙ | |||
196 197 198 199 200 201 202 | 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> | | | | 196 197 198 199 200 201 202 203 204 205 206 207 208 209 210 211 212 213 | 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: ^(<codeblock> 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 USING COVERING INDEX i2 (~1000000 rows) |
︙ | ︙ | |||
229 230 231 232 233 234 235 | 0|0|0|SEARCH TABLE t2 USING INDEX i4 (c=?) (~10 rows) 0|1|1|SCAN TABLE t1 (~1000000 rows) </codeblock>)^ <h2>Compound Queries</h2> <p> | | | | 229 230 231 232 233 234 235 236 237 238 239 240 241 242 243 244 | 0|0|0|SEARCH TABLE t2 USING INDEX i4 (c=?) (~10 rows) 0|1|1|SCAN TABLE t1 (~1000000 rows) </codeblock>)^ <h2>Compound Queries</h2> <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: ^(<codeblock> sqlite> EXPLAIN QUERY PLAN SELECT a FROM t1 UNION SELECT c FROM t2; 1|0|0|SCAN TABLE t1 (~1000000 rows) |
︙ | ︙ |