Documentation Source Text

Check-in [10b7c35b44]
Login

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

Overview
Comment:Add more requirements marks to the optoverview.html document.
Downloads: Tarball | ZIP archive
Timelines: family | ancestors | descendants | both | trunk
Files: files | file ages | folders
SHA1: 10b7c35b44dc97154abc39e57ca2498e645ca8af
User & Date: drh 2009-12-22 01:09:20.000
Context
2009-12-22
01:37
Update the download page to show all three self-synchronizing fossil repositories for the documentation sources. (check-in: 5e4ecf297e user: drh tags: trunk)
01:09
Add more requirements marks to the optoverview.html document. (check-in: 10b7c35b44 user: drh tags: trunk)
2009-12-21
17:10
Modify the evidence file HTMLization process to put evidence files in separate directories to avoid name collisions. (check-in: 95ddf6f2f8 user: drh tags: trunk)
Changes
Unified Diff Ignore Whitespace Patch
Changes to pages/optoverview.in.
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
  choices that provides the answer with a minimum of disk I/O and CPU
  overhead.
}

HEADING 1 {WHERE clause analysis} where_clause

PARAGRAPH {
  The WHERE clause on a query is broken up into "terms" where each term
  is separated from the others by an AND operator.
  If the WHERE clause is composed of constraints separate by the OR
  operator then the entire clause is considered to be a single "term"
  to which the <a href="#or_opt">OR-clause optimization</a> is applied.
}
PARAGRAPH {
  All terms of the WHERE clause are analyzed to see if they can be
  satisfied using indices.
  Terms that cannot be satisfied through the use of indices become







|

|







57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
  choices that provides the answer with a minimum of disk I/O and CPU
  overhead.
}

HEADING 1 {WHERE clause analysis} where_clause

PARAGRAPH {
  ^The WHERE clause on a query is broken up into "terms" where each term
  is separated from the others by an AND operator.
  ^If the WHERE clause is composed of constraints separate by the OR
  operator then the entire clause is considered to be a single "term"
  to which the <a href="#or_opt">OR-clause optimization</a> is applied.
}
PARAGRAPH {
  All terms of the WHERE clause are analyzed to see if they can be
  satisfied using indices.
  Terms that cannot be satisfied through the use of indices become
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
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260


261
262
263
264
265
266
267
268
269

270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285

286
287
288

289
290
291

292
293
294
295
296
297
298
299
  /expression/ < /column/
  /expression/ <= /column/
  /column/ IN (/expression-list/)
  /column/ IN (/subquery/)
  /column/ IS NULL
}
PARAGRAPH {
  If an index is created using a statement like this:
}
CODE {
  CREATE INDEX idx_ex1 ON ex1(a,b,c,d,e,...,y,z);
}
PARAGRAPH {
  Then the index might be used if the initial columns of the index
  (columns a, b, and so forth) appear in WHERE clause terms.
  The initial columns of the index must be used with
  the *=* or *IN* operators.  
  The right-most column that is used can employ inequalities.  
  For the right-most
  column of an index that is used, there can be up to two inequalities
  that must sandwich the allowed values of the column between two extremes.
}
PARAGRAPH {
  It is not necessary for every column of an index to appear in a
  WHERE clause term in order for that index to be used. 
  But there can not be gaps in the columns of the index that are used.
  Thus for the example index above, if there is no WHERE clause term
  that constraints column c, then terms that constrain columns a and b can
  be used with the index but not terms that constraint columns d through z.
  Similarly, no index column will be used (for indexing purposes)
  that is to the right of a 
  column that is constrained only by inequalities.
}
HEADING 2 {Index term usage examples}
PARAGRAPH {
  For the index above and WHERE clause like this:
}
CODE {
  ... WHERE a=5 AND b IN (1,2,3) AND c IS NULL AND d='hello'
}
PARAGRAPH {
  The first four columns a, b, c, and d of the index would be usable since
  those four columns form a prefix of the index and are all bound by
  equality constraints.
}
PARAGRAPH {
  For the index above and WHERE clause like this:
}
CODE {
  ... WHERE a=5 AND b IN (1,2,3) AND c>12 AND d='hello'
}
PARAGRAPH {
  Only columns a, b, and c of the index would be usable.  The d column
  would not be usable because it occurs to the right of c and c is
  constrained only by inequalities.
}
PARAGRAPH {
  For the index above and WHERE clause like this:
}
CODE {
  ... WHERE a=5 AND b IN (1,2,3) AND d='hello'
}
PARAGRAPH {
  Only columns a and b of the index would be usable.  The d column
  would not be usable because column c is not constrained and there can
  be no gaps in the set of columns that usable by the index.
}
PARAGRAPH {
  For the index above and WHERE clause like this:
}
CODE {
  ... WHERE b IN (1,2,3) AND c NOT NULL AND d='hello'
}
PARAGRAPH {
  The index is not usable at all becaues the left-most column of the
  index (column "a") is not constrained.  Assuming there are no other
  indices, the query above would result in a full table scan.
}
PARAGRAPH {
  For the index above and WHERE clause like this:
}
CODE {
  ... WHERE a=5 OR b IN (1,2,3) OR c NOT NULL OR d='hello'
}
PARAGRAPH {
  The index is not usable because the WHERE clause terms are connected
  by OR instead of AND. This query would result in a full table scan.
  However, if three additional indices where added that contained columns
  b, c, and d as their left-most columns, then the
  <a href="#or_opt">OR-clause optimization</a> might apply.
}

HEADING 1 {The BETWEEN optimization} between_opt

PARAGRAPH {
  If a term of the WHERE clause is of the following form:
}
SYNTAX {
  /expr1/ BETWEEN /expr2/ AND /expr3/
}
PARAGRAPH {
  Then two virtual terms are added as follows:
}
SYNTAX {
  /expr1/ >= /expr2/ AND /expr1/ <= /expr3/
}
PARAGRAPH {
  If both virtual terms end up being used as constraints on an index,
  then the original BETWEEN term is omitted and the corresponding test
  is not performed on input rows.
  Thus if the BETWEEN term ends up being used as an index constraint
  no tests are ever performed on that term.
  On the other hand, the
  virtual terms themselves never causes tests to be performed on
  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:
}
SYNTAX {
  /column/ = /expr1/ OR /column/ = /expr2/ OR /column/ = /expr3/ OR ...
}
PARAGRAPH {
  Then that term is rewritten as follows:
}
SYNTAX {
  /column/ IN (/expr1/,/expr2/,/expr3/,/expr4/,...)
}
PARAGRAPH {
  The rewritten term then might go on to constrain an index using the
  normal rules for *IN* operators.
  Note that <i>column</i> must be the same column in every OR-connected subterm,
  although the column can occur on either the left or the right side of
  the *=* operator.
}
PARAGRAPH {
  If and only if the previously described conversion of OR to an IN operator
  does not work, a second OR-clause optimization is attempted.
  Suppose the OR clause consists of multiple subterms as follows:
}
SYNTAX {
  /expr1/ OR /expr2/ OR /expr3/
}
PARAGRAPH {
  Individual subterms might be a single comparison expression like
  *a=5* or *x>y* or they can be LIKE or BETWEEN expressions, or a subterm
  can be a parenthesized list of AND-connected sub-subterms.
  Each subterm is analyzed as if it were itself the entire WHERE clause
  in order to see if the subterm is indexable by itself.
  If <u>every</u> subterm of an OR clause is separately indexable
  then the OR clause might be coded so that expression works something


  like the following:
}
SYNTAX {
  rowid IN (SELECT rowid FROM /table/ WHERE /expr1/
            UNION SELECT rowid FROM /table/ WHERE /expr2/
            UNION SELECT rowid FROM /table/ WHERE /expr3/)
}
PARAGRAPH {
  The expression above is conceptual.

  The actual implemention of the OR clause uses a mechanism that is
  more efficient than subqueries and which works even 
  even for tables where the "rowid" column name has been 
  overloaded for other uses and no longer refers to the real rowid.
  But the essence of the implementation is captured by the statement
  above:  Separate indices are used to find rowids that satisfy each
  subterm of the OR clause and then the union of those rowids is used
  to find all matching rows in the database.
}
PARAGRAPH {
  Note that in most cases, SQLite will only use a single index for each
  table in the FROM clause of a query.  The second OR-clause optimization
  described here is the one exception to that rule.  With an OR-clause,
  a different index might be used for each subterm in the OR-clause.
}
PARAGRAPH {

  The transformation of an OR clause to use indices is not guaranteed.
  SQLite uses a cost-based query planner.  It attempts to estimate the cost
  of evaluating each subterm of the OR clause separately and weights the

  total cost against the a full-table scan.  If there are many subterms
  in the OR clause or if some of the indices on OR-clause subterms are
  not very selective, then SQLite might decide that it is faster to do

  a full-table scan.  Programmers can use the
  [EXPLAIN | EXPLAIN QUERY PLAN] prefix on a statement to get a
  high-level overview of the chosen query strategy.
}

HEADING 1 {The LIKE optimization} like_opt
hd_keywords {LIKE optimization}








|






|
|

|
|




|

|
|


|





|







|


|







|


|







|


|






|



|






|
|







|










|
|


|

|


|









|











|
|
|
|




|
|









|

|
|
>
>
|







|
>
|



|
|
|
|




|



>
|
|
<
>
|
|
|
>
|







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
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291

292
293
294
295
296
297
298
299
300
301
302
303
304
  /expression/ < /column/
  /expression/ <= /column/
  /column/ IN (/expression-list/)
  /column/ IN (/subquery/)
  /column/ IS NULL
}
PARAGRAPH {
  ^(If an index is created using a statement like this:
}
CODE {
  CREATE INDEX idx_ex1 ON ex1(a,b,c,d,e,...,y,z);
}
PARAGRAPH {
  Then the index might be used if the initial columns of the index
  (columns a, b, and so forth) appear in WHERE clause terms.)^
  ^The initial columns of the index must be used with
  the *=* or *IN* operators.  
  ^The right-most column that is used can employ inequalities.  
  ^For the right-most
  column of an index that is used, there can be up to two inequalities
  that must sandwich the allowed values of the column between two extremes.
}
PARAGRAPH {
  ^It is not necessary for every column of an index to appear in a
  WHERE clause term in order for that index to be used. 
  ^But there can not be gaps in the columns of the index that are used.
  ^Thus for the example index above, if there is no WHERE clause term
  that constraints column c, then terms that constrain columns a and b can
  be used with the index but not terms that constraint columns d through z.
  ^Similarly, no index column will be used (for indexing purposes)
  that is to the right of a 
  column that is constrained only by inequalities.
}
HEADING 2 {Index term usage examples}
PARAGRAPH {
  ^(For the index above and WHERE clause like this:
}
CODE {
  ... WHERE a=5 AND b IN (1,2,3) AND c IS NULL AND d='hello'
}
PARAGRAPH {
  The first four columns a, b, c, and d of the index would be usable since
  those four columns form a prefix of the index and are all bound by
  equality constraints.)^
}
PARAGRAPH {
  ^(For the index above and WHERE clause like this:
}
CODE {
  ... WHERE a=5 AND b IN (1,2,3) AND c>12 AND d='hello'
}
PARAGRAPH {
  Only columns a, b, and c of the index would be usable.  The d column
  would not be usable because it occurs to the right of c and c is
  constrained only by inequalities.)^
}
PARAGRAPH {
  ^(For the index above and WHERE clause like this:
}
CODE {
  ... WHERE a=5 AND b IN (1,2,3) AND d='hello'
}
PARAGRAPH {
  Only columns a and b of the index would be usable.  The d column
  would not be usable because column c is not constrained and there can
  be no gaps in the set of columns that usable by the index.)^
}
PARAGRAPH {
  ^(For the index above and WHERE clause like this:
}
CODE {
  ... WHERE b IN (1,2,3) AND c NOT NULL AND d='hello'
}
PARAGRAPH {
  The index is not usable at all becaues the left-most column of the
  index (column "a") is not constrained.^)  ^Assuming there are no other
  indices, the query above would result in a full table scan.
}
PARAGRAPH {
  ^(For the index above and WHERE clause like this:
}
CODE {
  ... WHERE a=5 OR b IN (1,2,3) OR c NOT NULL OR d='hello'
}
PARAGRAPH {
  The index is not usable because the WHERE clause terms are connected
  by OR instead of AND.)^ ^This query would result in a full table scan.
  ^However, if three additional indices where added that contained columns
  b, c, and d as their left-most columns, then the
  <a href="#or_opt">OR-clause optimization</a> might apply.
}

HEADING 1 {The BETWEEN optimization} between_opt

PARAGRAPH {
  ^(If a term of the WHERE clause is of the following form:
}
SYNTAX {
  /expr1/ BETWEEN /expr2/ AND /expr3/
}
PARAGRAPH {
  Then two virtual terms are added as follows:
}
SYNTAX {
  /expr1/ >= /expr2/ AND /expr1/ <= /expr3/
}
PARAGRAPH {)^
  ^If both virtual terms end up being used as constraints on an index,
  then the original BETWEEN term is omitted and the corresponding test
  is not performed on input rows.
  ^Thus if the BETWEEN term ends up being used as an index constraint
  no tests are ever performed on that term.
  ^On the other hand, the
  virtual terms themselves never causes tests to be performed on
  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:
}
SYNTAX {
  /column/ = /expr1/ OR /column/ = /expr2/ OR /column/ = /expr3/ OR ...
}
PARAGRAPH {
  Then that term is rewritten as follows:
}
SYNTAX {
  /column/ IN (/expr1/,/expr2/,/expr3/,/expr4/,...)
}
PARAGRAPH {)^
  ^The rewritten term then might go on to constrain an index using the
  normal rules for *IN* operators.  ^Note that <i>column</i> must be
  the same column in every OR-connected subterm,
  although the column can occur on either the left or the right side of
  the *=* operator.
}
PARAGRAPH {
  ^If and only if the previously described conversion of OR to an IN operator
  does not work, the second OR-clause optimization is attempted.
  Suppose the OR clause consists of multiple subterms as follows:
}
SYNTAX {
  /expr1/ OR /expr2/ OR /expr3/
}
PARAGRAPH {
  Individual subterms might be a single comparison expression like
  *a=5* or *x>y* or they can be LIKE or BETWEEN expressions, or a subterm
  can be a parenthesized list of AND-connected sub-subterms.
  ^Each subterm is analyzed as if it were itself the entire WHERE clause
  in order to see if the subterm is indexable by itself.
  ^If <u>every</u> subterm of an OR clause is separately indexable
  then the OR clause might be coded such that a separate index is used
  to evaluate each term of the OR clause.  One way to think about how
  SQLite uses separate indices foreach each OR clause term is to imagine
  that the WHERE clause where rewritten as follows:
}
SYNTAX {
  rowid IN (SELECT rowid FROM /table/ WHERE /expr1/
            UNION SELECT rowid FROM /table/ WHERE /expr2/
            UNION SELECT rowid FROM /table/ WHERE /expr3/)
}
PARAGRAPH {
  ^The rewritten expression above is conceptual; WHERE clauses containing
  OR are not really rewritten this way.
  ^The actual implemention of the OR clause uses a mechanism that is
  more efficient than subqueries and which works even 
  even for tables where the "rowid" column name has been 
  overloaded for other uses and no longer refers to the real rowid.
  ^But the essence of the implementation is captured by the statement
  above:  Separate indices are used to find candidate result rows
  from each OR clause term and the final result is the union of
  those rows.
}
PARAGRAPH {
  Note that in most cases, SQLite will only use a single index for each
  table in the FROM clause of a query.  The second OR-clause optimization
  described here is the exception to that rule.  With an OR-clause,
  a different index might be used for each subterm in the OR-clause.
}
PARAGRAPH {
  ^For any given query, the fact that the OR-clause optimization described
  here can be used does not guarantee that it will be used.
  ^SQLite uses a cost-based query planner that estimates the CPU and

  disk I/O costs of various competing query plans and chooses the plan
  that it thinks will be the fastest.  ^If there are many OR terms in
  the WHERE clause or if some of the indices on individual OR-clause 
  subterms are not very selective, then SQLite might decide that it is
  faster to use a different query algorithm, or even a full-table scan.
  ^Application developers can use the
  [EXPLAIN | EXPLAIN QUERY PLAN] prefix on a statement to get a
  high-level overview of the chosen query strategy.
}

HEADING 1 {The LIKE optimization} like_opt
hd_keywords {LIKE optimization}

320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
      built-in NOCASE collating sequence.</li>
  </ol>
}
PARAGRAPH {
  The LIKE operator has two modes that can be set by a
  [case_sensitive_like | pragma].  ^The
  default mode is for LIKE comparisons to be insensitive to differences
  of case for latin1 characters.  Thus, by default, the following
  expression is true:
}
CODE {
  'a' LIKE 'A'
}
PARAGRAPH {
  By turning on the case_sensitive_like pragma as follows:
}
CODE {
  PRAGMA case_sensitive_like=ON;
}
PARAGRAPH {
  Then the LIKE operator pays attention to case and the example above would
  evaluate to false.  ^Note that case insensitivity only applies to
  latin1 characters - basically the upper and lower case letters of English
  in the lower 127 byte codes of ASCII.  ^International character sets
  are case sensitive in SQLite unless a application-defined
  [collating sequence] and [like | like() SQL function] are provided that
  take non-ASCII characters into account.







|





|
|




|







325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
      built-in NOCASE collating sequence.</li>
  </ol>
}
PARAGRAPH {
  The LIKE operator has two modes that can be set by a
  [case_sensitive_like | pragma].  ^The
  default mode is for LIKE comparisons to be insensitive to differences
  of case for latin1 characters.  ^(Thus, by default, the following
  expression is true:
}
CODE {
  'a' LIKE 'A'
}
PARAGRAPH {)^
  ^(But if the case_sensitive_like pragma is enabled as follows:
}
CODE {
  PRAGMA case_sensitive_like=ON;
}
PARAGRAPH {)^
  Then the LIKE operator pays attention to case and the example above would
  evaluate to false.  ^Note that case insensitivity only applies to
  latin1 characters - basically the upper and lower case letters of English
  in the lower 127 byte codes of ASCII.  ^International character sets
  are case sensitive in SQLite unless a application-defined
  [collating sequence] and [like | like() SQL function] are provided that
  take non-ASCII characters into account.
390
391
392
393
394
395
396
397
398
399
400
401
402
403
404
405
406
407
408
409

410
411
412
413
414
415
416
417
418
419
420
421
422
423
424
425
426
427
428
429
430
431
432
433
434
435
436
437
438
439
440
441
442
443
444
445
446
447
448
449
450
451
452
453
454
455
456
457
458
459

460
461
462
463
464
465
466
467
468
469
470
471
472
473
474
475
476
477
478
479
480
481
482
483
484
485
486
487
488
489
490
491
492
493
494
495
496
497
498
  Suppose the initial sequence of non-wildcard characters on the right-hand
  side of the LIKE or GLOB operator is <i>x</i>.  We are using a single 
  character to denote this non-wildcard prefix but the reader should
  understand that the prefix can consist of more than 1 character.
  Let <i>y</i> be the smallest string that is the same length as /x/ but which
  compares greater than <i>x</i>.  For example, if <i>x</i> is *hello* then
  <i>y</i> would be *hellp*.
  The LIKE and GLOB optimizations consist of adding two virtual terms
  like this:
}
SYNTAX {
  /column/ >= /x/ AND /column/ < /y/
}
PARAGRAPH {
  Under most circumstances, the original LIKE or GLOB operator is still
  tested against each input row even if the virtual terms are used to
  constrain an index.  This is because we do not know what additional
  constraints may be imposed by characters to the right
  of the <i>x</i> prefix.  However, ^if there is only a single global wildcard
  to the right of <i>x</i>, then the original LIKE or GLOB test is disabled.

  In other words, if the pattern is like this:
}
SYNTAX {
  /column/ LIKE /x/%
  /column/ GLOB /x/*
}
PARAGRAPH {
  Then the original LIKE or GLOB tests are disabled when the virtual
  terms constrain an index because in that case we know that all of the
  rows selected by the index will pass the LIKE or GLOB test.
}
PARAGRAPH {
  ^Note that when the right-hand side of a LIKE or GLOB operator is
  a [parameter] and the statement is prepared using [sqlite3_prepare_v2()]
  or [sqlite3_prepare16_v2()] then the statement is automatically reparsed
  and recompiled on the first [sqlite3_step()] call of each run if the binding
  to the right-hand side parameter has changed since the previous run.
  This reparse and recompile is essentially the same action that occurs
  following a schema change.  The recompile is necessary so that the query
  planner can examine the new value bound to the right-hand side of the
  LIKE or GLOB operator and determine whether or not to employ the
  optimization described above.
}
  

HEADING 1 {Joins} joins

PARAGRAPH {
  The ON and USING clauses of a inner join are converted into additional
  terms of the WHERE clause prior to WHERE clause analysis described
  above in paragraph 1.0.  Thus
  with SQLite, there is no advantage to use the newer SQL92 join syntax
  over the older SQL89 comma-join syntax.  They both end up accomplishing
  exactly the same thing on inner joins.
}
PARAGRAPH {
  For a LEFT OUTER JOIN the situation is more complex.  The following
  two queries are not equivalent:
}
CODE {
  SELECT * FROM tab1 LEFT JOIN tab2 ON tab1.x=tab2.y;
  SELECT * FROM tab1 LEFT JOIN tab2 WHERE tab1.x=tab2.y;
}
PARAGRAPH {
  For an inner join, the two queries above would be identical.  But
  special processing applies to the ON and USING clauses of an OUTER join:
  specifically, the constraints in an ON or USING clause do not apply if
  the right table of the join is on a null row, but the constraints do apply
  in the WHERE clause.  The net effect is that putting the ON 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 {
  The default order of the nested loops in a join is for the left-most
  table in the FROM clause to form the outer loop and the right-most
  table to form the inner loop.
  However, SQLite will nest the loops in a different order if doing so
  will help it to select better indices.
}
PARAGRAPH {
  Inner joins can be freely reordered.  However a left outer join is
  neither commutative nor associative and hence will not be reordered.
  Inner joins to the left and right of the outer join might be reordered
  if the optimizer thinks that is advantageous but the outer joins are
  always evaluated in the order in which they occur.
}
PARAGRAPH {
  When selecting the order of tables in a join, SQLite uses a greedy
  algorithm that runs in polynomial (O(N&sup2;)) time.  Because of this,
  SQLite is able to efficiently plan queries with 50- or 60-way joins.
}
PARAGRAPH {
  Join reordering is automatic and usually works well enough that
  programmer do not have to think about it, especially if [ANALYZE]
  has been used to gather statistics about the available indices.
  But occasionally some hints from the programmer are needed.
  Consider, for example, the following schema:
}
CODE {
  CREATE TABLE node(
     id INTEGER PRIMARY KEY,







|





|




|
|
>
|






|

|


















|

|
|

|


|






|
|



|
|
>














|



|

|




|
|




|







395
396
397
398
399
400
401
402
403
404
405
406
407
408
409
410
411
412
413
414
415
416
417
418
419
420
421
422
423
424
425
426
427
428
429
430
431
432
433
434
435
436
437
438
439
440
441
442
443
444
445
446
447
448
449
450
451
452
453
454
455
456
457
458
459
460
461
462
463
464
465
466
467
468
469
470
471
472
473
474
475
476
477
478
479
480
481
482
483
484
485
486
487
488
489
490
491
492
493
494
495
496
497
498
499
500
501
502
503
504
505
  Suppose the initial sequence of non-wildcard characters on the right-hand
  side of the LIKE or GLOB operator is <i>x</i>.  We are using a single 
  character to denote this non-wildcard prefix but the reader should
  understand that the prefix can consist of more than 1 character.
  Let <i>y</i> be the smallest string that is the same length as /x/ but which
  compares greater than <i>x</i>.  For example, if <i>x</i> is *hello* then
  <i>y</i> would be *hellp*.
  ^(The LIKE and GLOB optimizations consist of adding two virtual terms
  like this:
}
SYNTAX {
  /column/ >= /x/ AND /column/ < /y/
}
PARAGRAPH {)^
  Under most circumstances, the original LIKE or GLOB operator is still
  tested against each input row even if the virtual terms are used to
  constrain an index.  This is because we do not know what additional
  constraints may be imposed by characters to the right
  of the <i>x</i> prefix.  However, ^if there is only a single
  global wildcard to the right of <i>x</i>, then the original LIKE or 
  GLOB test is disabled.
  ^(In other words, if the pattern is like this:
}
SYNTAX {
  /column/ LIKE /x/%
  /column/ GLOB /x/*
}
PARAGRAPH {
  then the original LIKE or GLOB tests are disabled when the virtual
  terms constrain an index because in that case we know that all of the
  rows selected by the index will pass the LIKE or GLOB test.)^
}
PARAGRAPH {
  ^Note that when the right-hand side of a LIKE or GLOB operator is
  a [parameter] and the statement is prepared using [sqlite3_prepare_v2()]
  or [sqlite3_prepare16_v2()] then the statement is automatically reparsed
  and recompiled on the first [sqlite3_step()] call of each run if the binding
  to the right-hand side parameter has changed since the previous run.
  This reparse and recompile is essentially the same action that occurs
  following a schema change.  The recompile is necessary so that the query
  planner can examine the new value bound to the right-hand side of the
  LIKE or GLOB operator and determine whether or not to employ the
  optimization described above.
}
  

HEADING 1 {Joins} joins

PARAGRAPH {
  ^The ON and USING clauses of a inner join are converted into additional
  terms of the WHERE clause prior to WHERE clause analysis described
  above in paragraph 1.0.  ^(Thus with SQLite, there is no computational
  advantage to use the newer SQL92 join syntax
  over the older SQL89 comma-join syntax.  They both end up accomplishing
  exactly the same thing on inner joins.)^
}
PARAGRAPH {
  For a LEFT OUTER JOIN the situation is more complex.  ^(The following
  two queries are not equivalent:
}
CODE {
  SELECT * FROM tab1 LEFT JOIN tab2 ON tab1.x=tab2.y;
  SELECT * FROM tab1 LEFT JOIN tab2 WHERE tab1.x=tab2.y;
}
PARAGRAPH {)^
  ^For an inner join, the two queries above would be identical.  ^But
  special processing applies to the ON and USING clauses of an OUTER join:
  specifically, the constraints in an ON or USING clause do not apply if
  the right table of the join is on a null row, but the constraints do apply
  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 {
  The default order of the nested loops in a join is for the left-most
  table in the FROM clause to form the outer loop and the right-most
  table to form the inner loop.
  ^However, SQLite will nest the loops in a different order if doing so
  will help it to select better indices.
}
PARAGRAPH {
  ^Inner joins can be freely reordered.  ^However a left outer join is
  neither commutative nor associative and hence will not be reordered.
  ^Inner joins to the left and right of the outer join might be reordered
  if the optimizer thinks that is advantageous but the outer joins are
  always evaluated in the order in which they occur.
}
PARAGRAPH {
  ^When selecting the order of tables in a join, SQLite uses a greedy
  algorithm that runs in polynomial (O(N&sup2;)) time.  ^Because of this,
  SQLite is able to efficiently plan queries with 50- or 60-way joins.
}
PARAGRAPH {
  Join reordering is automatic and usually works well enough that
  programmers do not have to think about it, especially if [ANALYZE]
  has been used to gather statistics about the available indices.
  But occasionally some hints from the programmer are needed.
  Consider, for example, the following schema:
}
CODE {
  CREATE TABLE node(
     id INTEGER PRIMARY KEY,
583
584
585
586
587
588
589
590
591
592
593
594
595
596
597
598
599
  each, resulting in 12 million iterations of the middle loop.
  Thus in the second scenario, option 2 is nearly 2000 times faster
  than option 1.
}
PARAGRAPH {
  So you can see that depending on how the data is structured in the table,
  either query plan 1 or query plan 2 might be better.  Which plan does
  SQLite choose by default?  As of version 3.6.18, without running [ANALYZE],
  SQLite will choose option 2.
  But if the [ANALYZE] command is run in order to gather statistics,
  a different choice might be made if the statistics indicate that the
  alternative is likely to run faster.
}

HEADING 2 {Manual Control Of Query Plans}

PARAGRAPH {







|
|
|







590
591
592
593
594
595
596
597
598
599
600
601
602
603
604
605
606
  each, resulting in 12 million iterations of the middle loop.
  Thus in the second scenario, option 2 is nearly 2000 times faster
  than option 1.
}
PARAGRAPH {
  So you can see that depending on how the data is structured in the table,
  either query plan 1 or query plan 2 might be better.  Which plan does
  SQLite choose by default?  ^(As of version 3.6.18, without running [ANALYZE],
  SQLite will choose option 2.)^
  ^But if the [ANALYZE] command is run in order to gather statistics,
  a different choice might be made if the statistics indicate that the
  alternative is likely to run faster.
}

HEADING 2 {Manual Control Of Query Plans}

PARAGRAPH {
617
618
619
620
621
622
623
624
625
626
627
628
629
630
631
632
633
634
635
636
637
638
639
640
641
642
643
644
645
646
647
648
649
650
651
652
653
654
655
656
657
658
659
660
661
662
663
664
  from the prototype database into these new statistics tables.
  In that way, statistics from large working data sets can be preloaded
  into newly created application files.
}
PARAGRAPH {
  If you really must take manual control of join loop nesting order,
  the preferred method is to use some peculiar (though valid) SQL syntax
  to specify the join. If you use the keyword CROSS in a join, then 
  the two tables connected by that join will not be reordered.
  So in the query, the optimizer is free to reorder the tables of
  the FROM clause anyway it sees fit:
}
CODE {
  SELECT *
    FROM node AS n1,
         edge AS e,
         node AS n2
   WHERE n1.name = 'alice'
     AND n2.name = 'bob'
     AND e.orig = n1.id
     AND e.dest = n2.id;
}
PARAGRAPH {
  But in the following logically equivalent formulation of the query,
  the substitution of "CROSS JOIN" for the "," means that the order
  of tables must be N1, E, N2.
}
CODE {
  SELECT *
    FROM node AS n1 CROSS JOIN
         edge AS e CROSS JOIN
         node AS n2
   WHERE n1.name = 'alice'
     AND n2.name = 'bob'
     AND e.orig = n1.id
     AND e.dest = n2.id;
}
PARAGRAPH {
  Hence, in the second form, the query plan must be option 2. Note that
  you must use the keyword CROSS in order to disable the table reordering
  optimization. INNER JOIN, NATURAL JOIN, JOIN, and other similar
  combinations work just like a comma join in that the optimizer is
  free to reorder tables as it sees fit. (Table reordering is also
  disabled on an outer join, but that is because outer joins are not
  associative or commutative. Reordering tables in outer joins changes
  the result.)
}








|

|












|
|













|
|

|







624
625
626
627
628
629
630
631
632
633
634
635
636
637
638
639
640
641
642
643
644
645
646
647
648
649
650
651
652
653
654
655
656
657
658
659
660
661
662
663
664
665
666
667
668
669
670
671
  from the prototype database into these new statistics tables.
  In that way, statistics from large working data sets can be preloaded
  into newly created application files.
}
PARAGRAPH {
  If you really must take manual control of join loop nesting order,
  the preferred method is to use some peculiar (though valid) SQL syntax
  to specify the join.  ^If you use the keyword CROSS in a join, then 
  the two tables connected by that join will not be reordered.
  ^(So in the query, the optimizer is free to reorder the tables of
  the FROM clause anyway it sees fit:
}
CODE {
  SELECT *
    FROM node AS n1,
         edge AS e,
         node AS n2
   WHERE n1.name = 'alice'
     AND n2.name = 'bob'
     AND e.orig = n1.id
     AND e.dest = n2.id;
}
PARAGRAPH {)^
  ^(But in the following logically equivalent formulation of the query,
  the substitution of "CROSS JOIN" for the "," means that the order
  of tables must be N1, E, N2.
}
CODE {
  SELECT *
    FROM node AS n1 CROSS JOIN
         edge AS e CROSS JOIN
         node AS n2
   WHERE n1.name = 'alice'
     AND n2.name = 'bob'
     AND e.orig = n1.id
     AND e.dest = n2.id;
}
PARAGRAPH {)^
  Hence, in the second form, the query plan must be option 2.  ^Note that
  you must use the keyword CROSS in order to disable the table reordering
  optimization; INNER JOIN, NATURAL JOIN, JOIN, and other similar
  combinations work just like a comma join in that the optimizer is
  free to reorder tables as it sees fit. (Table reordering is also
  disabled on an outer join, but that is because outer joins are not
  associative or commutative. Reordering tables in outer joins changes
  the result.)
}

689
690
691
692
693
694
695
696
697
698
699
700
701
702
703
704
705
706
707
708
709
710
711
712
713
714
715
716
717
718
719
720
721
722
723
724
725
726
727
728
729
730
731
732
733
734
735
736
737
738
739
740
741
742
743
744
745
746
  When faced with a choice of two or more indices, SQLite tries to estimate
  the total amount of work needed to perform the query using each option.
  It then selects the option that gives the least estimated work.
}
PARAGRAPH {
  To help the optimizer get a more accurate estimate of the work involved
  in using various indices, the user may optionally run the [ANALYZE] command.
  The [ANALYZE] command scans all indices of database where there might
  be a choice between two or more indices and gathers statistics on the
  selectiveness of those indices.  The statistics gathered by
  this scan are stored in special database tables names shows names all
  begin with "<b>sqlite_stat</b>".
  The content of these tables is not updated as the database
  changes so after making significant changes it might be prudent to
  rerun [ANALYZE].
  The results of an ANALYZE command are only available to database connections
  that are opened after the ANALYZE command completes.
}
PARAGRAPH {
  The various <b>sqlite_stat</b><i>N</i> tables contain information on how
  selective the various indices are.  For example, the <b>sqlite_stat1</b>
  table might indicate that an equality constraint on column x reduces the
  search space to 10 rows on average, whereas an equality constraint on
  column y reduces the search space to 3 rows on average.  In that case,
  SQLite would prefer to use index ex2i2 since that index.
}
PARAGRAPH {
  Terms of the WHERE clause can be manually disqualified for use with
  indices by prepending a unary *+* operator to the column name.  The
  unary *+* is a no-op and will not slow down the evaluation of the test
  specified by the term.
  But it will prevent the term from constraining an index.
  So, in the example above, if the query were rewritten as:
}
CODE {
  SELECT z FROM ex2 WHERE +x=5 AND y=6;
}
PARAGRAPH {
  The *+* operator on the *x* column will prevent that term from 
  constraining an index.  This would force the use of the ex2i2 index.
}
PARAGRAPH {
  Note that the unary *+* operator also removes 
  <a href="datatype3.html#affinity">type affinity</a> from
  an expression, and in some cases this can cause subtle changes in
  the meaning of an expression.
  In the example above,
  if column *x* has <a href="datatype3.html#affinity">TEXT affinity</a>
  then the comparison "x=5" will be done as text.  But the *+* operator
  removes the affinity.  So the comparison "+x=5" will compare the text
  in column *x* with the numeric value 5 and will always be false.
}

HEADING 2 {Range Queries} rangequery
hd_keywords {range query optimization}

PARAGRAPH {
  Consider a slightly different scenario:







|

|


|


|




|



|


|
|



|






|


|



|



|







696
697
698
699
700
701
702
703
704
705
706
707
708
709
710
711
712
713
714
715
716
717
718
719
720
721
722
723
724
725
726
727
728
729
730
731
732
733
734
735
736
737
738
739
740
741
742
743
744
745
746
747
748
749
750
751
752
753
  When faced with a choice of two or more indices, SQLite tries to estimate
  the total amount of work needed to perform the query using each option.
  It then selects the option that gives the least estimated work.
}
PARAGRAPH {
  To help the optimizer get a more accurate estimate of the work involved
  in using various indices, the user may optionally run the [ANALYZE] command.
  ^The [ANALYZE] command scans all indices of database where there might
  be a choice between two or more indices and gathers statistics on the
  selectiveness of those indices.  ^The statistics gathered by
  this scan are stored in special database tables names shows names all
  begin with "<b>sqlite_stat</b>".
  ^The content of these tables is not updated as the database
  changes so after making significant changes it might be prudent to
  rerun [ANALYZE].
  ^The results of an ANALYZE command are only available to database connections
  that are opened after the ANALYZE command completes.
}
PARAGRAPH {
  The various <b>sqlite_stat</b><i>N</i> tables contain information on how
  selective the various indices are.  ^(For example, the <b>sqlite_stat1</b>
  table might indicate that an equality constraint on column x reduces the
  search space to 10 rows on average, whereas an equality constraint on
  column y reduces the search space to 3 rows on average.  In that case,
  SQLite would prefer to use index ex2i2 since that index.)^
}
PARAGRAPH {
  ^Terms of the WHERE clause can be manually disqualified for use with
  indices by prepending a unary *+* operator to the column name.  ^The
  unary *+* is a no-op and will not slow down the evaluation of the test
  specified by the term.
  But it will prevent the term from constraining an index.
  ^(So, in the example above, if the query were rewritten as:
}
CODE {
  SELECT z FROM ex2 WHERE +x=5 AND y=6;
}
PARAGRAPH {
  The *+* operator on the *x* column will prevent that term from 
  constraining an index.  This would force the use of the ex2i2 index.)^
}
PARAGRAPH {
  ^Note that the unary *+* operator also removes 
  <a href="datatype3.html#affinity">type affinity</a> from
  an expression, and in some cases this can cause subtle changes in
  the meaning of an expression.
  ^(In the example above,
  if column *x* has <a href="datatype3.html#affinity">TEXT affinity</a>
  then the comparison "x=5" will be done as text.  But the *+* operator
  removes the affinity.  So the comparison "+x=5" will compare the text
  in column *x* with the numeric value 5 and will always be false.)^
}

HEADING 2 {Range Queries} rangequery
hd_keywords {range query optimization}

PARAGRAPH {
  Consider a slightly different scenario:
757
758
759
760
761
762
763
764
765
766
767
768
769
770
771
772
773
774
775
776
777
778
779
780
781
782
783
784
785
786
787
788
789
790
791
792
793
794
795
796
797
798
799
800
801
802
803
804
805
806
807
808
809
810
811
812
813
814
815
816
817
818
819
820
821
822
823
824
825
826
827
828
829
830
831
832
833
834
835
836
837
838
839
840
841
842
843
844
845
846
847
848
849
850
851
852
853
854
855
856
857
858
859
860
861
862
863
864
865
866
867
868
869
870
871
872
873
874
875
876
877
878
879
880
881
882
883
884
885
886
887
888
889
890
891
892
893
894
895
896
897
898
899
900
901
902
903
904
905
906
907
908
909
910
911
912
913
914
915
916
917
918
919
920
921
922
923
924
925
926
927
928
929
930
931
932
933
934
935
936
937
938
939
940
941
942
943
944
945
946
947
948
949
  that span between 0 and 1,000.  In that scenario,
  the range constraint on column x should reduce the search space by
  a factor of 10,000 whereas the range constraint on column y should
  reduce the search space by a factor of only 10.  So the ex2i1 index
  should be preferred.
}
PARAGRAPH {
  SQLite will make this determination, but only if it has been compiled
  with [SQLITE_ENABLE_STAT2].  The [SQLITE_ENABLE_STAT2] option causes
  the [ANALYZE] command to collect a histogram of column content in the
  <b>sqlite_stat2</b> table and to use this histogram to make a better
  guess at the best query to use for range constraints such as the above.
}
PARAGRAPH {
  The histogram data is only useful if the right-hand side of the constraint
  is a compile-time constant.  Consider this query:
}
CODE {
  SELECT z FROM ex2 WHERE x BETWEEN ? AND ? AND y BETWEEN ? AND ?
}
PARAGRAPH {
  Because the bounds on columns x and y are [parameters] and are unknown
  to the query planner, SQLite has no way of using the histogram data in
  <b>sqlite_stat2</b> and so the index choice falls back to being
  arbitrary.
}
PARAGRAPH {
  Another limitation of the histogram data is that it only applies to the
  left-most column on an index.  Consider this scenario:
}
CODE {
  CREATE TABLE ex3(w,x,y,z);
  CREATE INDEX ex3i1 ON ex2(w, x);
  CREATE INDEX ex3i2 ON ex2(w, y);
  SELECT z FROM ex3 WHERE w=5 AND x BETWEEN 1 AND 100 AND y BETWEEN 1 AND 100;
}
PARAGRAPH {
  Here the inequalities are on columns x and y which are not the
  left-most index columns.  Hence, the histogram data which is collected no
  left-most column of indices is useless in helping to choose between the
  range constraints on columns x and y.
}

HEADING 1 {Avoidance of table lookups} index_only

PARAGRAPH {
  When doing an indexed lookup of a row, the usual procedure is to
  do a binary search on the index to find the index entry, then extract
  the [rowid] from the index and use that [rowid] to do a binary search on
  the original table.  Thus a typical indexed lookup involves two
  binary searches.
  If, however, all columns that were to be fetched from the table are
  already available in the index itself, SQLite will use the values
  contained in the index and will never look up the original table
  row.  This saves one binary search for each row and can make many
  queries run twice as fast.
}

HEADING 1 {ORDER BY optimizations} order_by

PARAGRAPH {
  SQLite attempts to use an index to satisfy the ORDER BY clause of a
  query when possible.
  When faced with the choice of using an index to satisfy WHERE clause
  constraints or satisfying an ORDER BY clause, SQLite does the same
  work analysis described in section 6.0
  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 default
  behavior is to evaluate the subquery into a transient table, then run
  the outer SELECT against the transient table. 
  This is problematic since the transient table will not have any indices
  and the outer query (which is likely a join) will be forced to do a
  full table scan on the transient table.
}
PARAGRAPH {
  To overcome this problem, SQLite attempts to flatten subqueries in
  the FROM clause of a SELECT.
  This involves inserting the FROM clause of the subquery into the
  FROM clause of the outer query and rewriting expressions in
  the outer query that refer to the result set of the subquery.
  For example:
}
CODE {
  SELECT a FROM (SELECT x+y AS a FROM t1 WHERE z<100) WHERE a>5
}
PARAGRAPH {
  Would be rewritten using query flattening as:
}
CODE {
  SELECT x+y AS a FROM t1 WHERE z<100 AND a>5
}
PARAGRAPH {
  There is a long list of conditions that must all be met in order for
  query flattening to occur.
}
PARAGRAPH {
  <ol>
  <li>  The subquery and the outer query do not both use aggregates.

  <li>  The subquery is not an aggregate or the outer query is not a join.

  <li>  The subquery is not the right operand of a left outer join.

  <li>  The subquery is not DISTINCT or the outer query is not a join.

  <li>  The subquery is not DISTINCT or the outer query does not use
        aggregates.

  <li>  The subquery does not use aggregates or the outer query is not
        DISTINCT.

  <li>  The subquery has a FROM clause.

  <li>  The subquery does not use LIMIT or the outer query is not a join.

  <li>  The subquery does not use LIMIT or the outer query does not use
        aggregates.

  <li>  The subquery does not use aggregates or the outer query does not
        use LIMIT.

  <li>  The subquery and the outer query do not both have ORDER BY clauses.

  <li>  The subquery and outer query do not both use LIMIT

  <li>  The subquery does not use OFFSET

  <li>  The outer query is not part of a compound select or the
        subquery does not have both an ORDER BY and a LIMIT clause.

  <li>  The outer query is not an aggregate or the subquery does
        not contain ORDER BY. 

  <li>  The sub-query is not a compound select, or it is a UNION ALL 
        compound clause made up entirely of non-aggregate queries, and 
        the parent query:

        <ul>
        <li> is not itself part of a compound select,
        <li> is not an aggregate or DISTINCT query, and
        <li> has no other tables or sub-selects in the FROM clause.
        </ul>

        The parent and sub-query may contain WHERE clauses. Subject to
        rules (11), (12) and (13), they may also contain ORDER BY,
        LIMIT and OFFSET clauses.

  <li>  If the sub-query is a compound select, then all terms of the
        ORDER by clause of the parent must be simple references to 
        columns of the sub-query.

  <li>  The subquery does not use LIMIT or the outer query does not
        have a WHERE clause.

  <li>  If the sub-query is a compound select, then it must not use
        an ORDER BY clause.
  </ol>
}
PARAGRAPH {
  The casual reader is not expected to understand or remember any part of
  the list above.  The point of this list is to demonstrate
  that the decision of whether or not to flatten a query is complex.
  
}
PARAGRAPH {
  Query flattening is an important optimization when views are used as
  each use of a view is translated into a subquery.
}

HEADING 1 {The MIN/MAX optimization} minmax

PARAGRAPH {
  Queries of the following forms will be optimized to run in logarithmic
  time assuming appropriate indices exist:
}
CODE {
  SELECT MIN(x) FROM table;
  SELECT MAX(x) FROM table;
}
PARAGRAPH {
  In order for these optimizations to occur, they must appear in exactly
  the form shown above - changing only the name of the table and column.
  It is not permissible to add a WHERE clause or do any arithmetic on the
  result.  The result set must contain a single column.
  The column in the MIN or MAX function must be an indexed column.
}
</tcl>







|
|





|
|

<
<
<

<
<
<
<
<
<
|










|












|









|

|

|







|

|
|




|




|










|





|

|

|

|

|


|


|

|

|


|


|

|

|

|


|


|







|

|



|



|


|

















|






|
|

|
|
|


764
765
766
767
768
769
770
771
772
773
774
775
776
777
778
779
780



781






782
783
784
785
786
787
788
789
790
791
792
793
794
795
796
797
798
799
800
801
802
803
804
805
806
807
808
809
810
811
812
813
814
815
816
817
818
819
820
821
822
823
824
825
826
827
828
829
830
831
832
833
834
835
836
837
838
839
840
841
842
843
844
845
846
847
848
849
850
851
852
853
854
855
856
857
858
859
860
861
862
863
864
865
866
867
868
869
870
871
872
873
874
875
876
877
878
879
880
881
882
883
884
885
886
887
888
889
890
891
892
893
894
895
896
897
898
899
900
901
902
903
904
905
906
907
908
909
910
911
912
913
914
915
916
917
918
919
920
921
922
923
924
925
926
927
928
929
930
931
932
933
934
935
936
937
938
939
940
941
942
943
944
945
946
947
  that span between 0 and 1,000.  In that scenario,
  the range constraint on column x should reduce the search space by
  a factor of 10,000 whereas the range constraint on column y should
  reduce the search space by a factor of only 10.  So the ex2i1 index
  should be preferred.
}
PARAGRAPH {
  ^SQLite will make this determination, but only if it has been compiled
  with [SQLITE_ENABLE_STAT2].  ^The [SQLITE_ENABLE_STAT2] option causes
  the [ANALYZE] command to collect a histogram of column content in the
  <b>sqlite_stat2</b> table and to use this histogram to make a better
  guess at the best query to use for range constraints such as the above.
}
PARAGRAPH {
  ^The histogram data is only useful if the right-hand side of the constraint
  is a simple compile-time constant or [parameter] and not an expression.
}



PARAGRAPH {






  ^Another limitation of the histogram data is that it only applies to the
  left-most column on an index.  Consider this scenario:
}
CODE {
  CREATE TABLE ex3(w,x,y,z);
  CREATE INDEX ex3i1 ON ex2(w, x);
  CREATE INDEX ex3i2 ON ex2(w, y);
  SELECT z FROM ex3 WHERE w=5 AND x BETWEEN 1 AND 100 AND y BETWEEN 1 AND 100;
}
PARAGRAPH {
  Here the inequalities are on columns x and y which are not the
  left-most index columns.  ^Hence, the histogram data which is collected no
  left-most column of indices is useless in helping to choose between the
  range constraints on columns x and y.
}

HEADING 1 {Avoidance of table lookups} index_only

PARAGRAPH {
  When doing an indexed lookup of a row, the usual procedure is to
  do a binary search on the index to find the index entry, then extract
  the [rowid] from the index and use that [rowid] to do a binary search on
  the original table.  Thus a typical indexed lookup involves two
  binary searches.
  ^If, however, all columns that were to be fetched from the table are
  already available in the index itself, SQLite will use the values
  contained in the index and will never look up the original table
  row.  This saves one binary search for each row and can make many
  queries run twice as fast.
}

HEADING 1 {ORDER BY optimizations} order_by

PARAGRAPH {
  ^SQLite attempts to use an index to satisfy the ORDER BY clause of a
  query when possible.
  ^When faced with the choice of using an index to satisfy WHERE clause
  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
  full table scan on the transient table.
}
PARAGRAPH {
  ^To overcome this problem, SQLite attempts to flatten subqueries in
  the FROM clause of a SELECT.
  This involves inserting the FROM clause of the subquery into the
  FROM clause of the outer query and rewriting expressions in
  the outer query that refer to the result set of the subquery.
  ^(For example:
}
CODE {
  SELECT a FROM (SELECT x+y AS a FROM t1 WHERE z<100) WHERE a>5
}
PARAGRAPH {
  Would be rewritten using query flattening as:
}
CODE {
  SELECT x+y AS a FROM t1 WHERE z<100 AND a>5
}
PARAGRAPH {)^
  There is a long list of conditions that must all be met in order for
  query flattening to occur.
}
PARAGRAPH {
  <ol>
  <li>  ^The subquery and the outer query do not both use aggregates.

  <li>  ^The subquery is not an aggregate or the outer query is not a join.

  <li>  ^The subquery is not the right operand of a left outer join.

  <li>  ^The subquery is not DISTINCT or the outer query is not a join.

  <li>  ^The subquery is not DISTINCT or the outer query does not use
        aggregates.

  <li>  ^The subquery does not use aggregates or the outer query is not
        DISTINCT.

  <li>  ^The subquery has a FROM clause.

  <li>  ^The subquery does not use LIMIT or the outer query is not a join.

  <li>  ^The subquery does not use LIMIT or the outer query does not use
        aggregates.

  <li>  ^The subquery does not use aggregates or the outer query does not
        use LIMIT.

  <li>  ^The subquery and the outer query do not both have ORDER BY clauses.

  <li>  ^The subquery and outer query do not both use LIMIT.

  <li>  ^The subquery does not use OFFSET.

  <li>  ^The outer query is not part of a compound select or the
        subquery does not have both an ORDER BY and a LIMIT clause.

  <li>  ^The outer query is not an aggregate or the subquery does
        not contain ORDER BY. 

  <li>  ^(The sub-query is not a compound select, or it is a UNION ALL 
        compound clause made up entirely of non-aggregate queries, and 
        the parent query:

        <ul>
        <li> is not itself part of a compound select,
        <li> is not an aggregate or DISTINCT query, and
        <li> has no other tables or sub-selects in the FROM clause.
        </ul>)^

        ^The parent and sub-query may contain WHERE clauses. ^Subject to
        rules (11), (12) and (13), they may also contain ORDER BY,
        LIMIT and OFFSET clauses.

  <li>  ^If the sub-query is a compound select, then all terms of the
        ORDER by clause of the parent must be simple references to 
        columns of the sub-query.

  <li>  ^The subquery does not use LIMIT or the outer query does not
        have a WHERE clause.

  <li>  ^If the sub-query is a compound select, then it must not use
        an ORDER BY clause.
  </ol>
}
PARAGRAPH {
  The casual reader is not expected to understand or remember any part of
  the list above.  The point of this list is to demonstrate
  that the decision of whether or not to flatten a query is complex.
  
}
PARAGRAPH {
  Query flattening is an important optimization when views are used as
  each use of a view is translated into a subquery.
}

HEADING 1 {The MIN/MAX optimization} minmax

PARAGRAPH {
  ^(Queries of the following forms will be optimized to run in logarithmic
  time assuming appropriate indices exist:
}
CODE {
  SELECT MIN(x) FROM table;
  SELECT MAX(x) FROM table;
}
PARAGRAPH {)^
  ^In order for these optimizations to occur, they must appear in exactly
  the form shown above - changing only the name of the table and column.
  ^It is not permissible to add a WHERE clause or do any arithmetic on the
  result.  ^The result set must contain a single column.
  ^The column in the MIN or MAX function must be an indexed column.
}
</tcl>