xref: /sqlite-3.40.0/test/analyze3.test (revision a3fdec71)
1# 2009 August 06
2#
3# The author disclaims copyright to this source code.  In place of
4# a legal notice, here is a blessing:
5#
6#    May you do good and not evil.
7#    May you find forgiveness for yourself and forgive others.
8#    May you share freely, never taking more than you give.
9#
10#***********************************************************************
11#
12# This file implements regression tests for SQLite library. This file
13# implements tests for range and LIKE constraints that use bound variables
14# instead of literal constant arguments.
15#
16
17set testdir [file dirname $argv0]
18source $testdir/tester.tcl
19
20ifcapable !stat4&&!stat3 {
21  finish_test
22  return
23}
24
25#----------------------------------------------------------------------
26# Test Organization:
27#
28# analyze3-1.*: Test that the values of bound parameters are considered
29#               in the same way as constants when planning queries that
30#               use range constraints.
31#
32# analyze3-2.*: Test that the values of bound parameters are considered
33#               in the same way as constants when planning queries that
34#               use LIKE expressions in the WHERE clause.
35#
36# analyze3-3.*: Test that binding to a variable does not invalidate the
37#               query plan when there is no way in which replanning the
38#               query may produce a superior outcome.
39#
40# analyze3-4.*: Test that SQL or authorization callback errors occuring
41#               within sqlite3Reprepare() are handled correctly.
42#
43# analyze3-5.*: Check that the query plans of applicable statements are
44#               invalidated if the values of SQL parameter are modified
45#               using the clear_bindings() or transfer_bindings() APIs.
46#
47# analyze3-6.*: Test that the problem fixed by commit [127a5b776d] is fixed.
48#
49
50proc getvar {varname} { uplevel #0 set $varname }
51db function var getvar
52
53proc eqp {sql {db db}} {
54  uplevel execsql [list "EXPLAIN QUERY PLAN $sql"] $db
55}
56
57proc sf_execsql {sql {db db}} {
58  set ::sqlite_search_count 0
59  set r [uplevel [list execsql $sql $db]]
60
61  concat $::sqlite_search_count [$db status step] $r
62}
63
64#-------------------------------------------------------------------------
65#
66# analyze3-1.1.1:
67#   Create a table with two columns. Populate the first column (affinity
68#   INTEGER) with integer values from 100 to 1100. Create an index on this
69#   column. ANALYZE the table.
70#
71# analyze3-1.1.2 - 3.1.3
72#   Show that there are two possible plans for querying the table with
73#   a range constraint on the indexed column - "full table scan" or "use
74#   the index". When the range is specified using literal values, SQLite
75#   is able to pick the best plan based on the samples in sqlite_stat3.
76#
77# analyze3-1.1.4 - 3.1.9
78#   Show that using SQL variables produces the same results as using
79#   literal values to constrain the range scan.
80#
81#   These tests also check that the compiler code considers column
82#   affinities when estimating the number of rows scanned by the "use
83#   index strategy".
84#
85do_test analyze3-1.1.1 {
86  execsql {
87    BEGIN;
88    CREATE TABLE t1(x INTEGER, y);
89    CREATE INDEX i1 ON t1(x);
90  }
91  for {set i 0} {$i < 1000} {incr i} {
92    execsql { INSERT INTO t1 VALUES($i+100, $i) }
93  }
94  execsql {
95    COMMIT;
96    ANALYZE;
97  }
98
99  ifcapable stat4 {
100    execsql { SELECT count(*)>0 FROM sqlite_stat4; }
101  } else {
102    execsql { SELECT count(*)>0 FROM sqlite_stat3; }
103  }
104} {1}
105
106do_eqp_test analyze3-1.1.2 {
107  SELECT sum(y) FROM t1 WHERE x>200 AND x<300
108} {0 0 0 {SEARCH TABLE t1 USING INDEX i1 (x>? AND x<?)}}
109do_eqp_test analyze3-1.1.3 {
110  SELECT sum(y) FROM t1 WHERE x>0 AND x<1100
111} {0 0 0 {SEARCH TABLE t1 USING INDEX i1 (x>? AND x<?)}}
112
113do_test analyze3-1.1.4 {
114  sf_execsql { SELECT sum(y) FROM t1 WHERE x>200 AND x<300 }
115} {199 0 14850}
116do_test analyze3-1.1.5 {
117  set l [string range "200" 0 end]
118  set u [string range "300" 0 end]
119  sf_execsql { SELECT sum(y) FROM t1 WHERE x>$l AND x<$u }
120} {199 0 14850}
121do_test analyze3-1.1.6 {
122  set l [expr int(200)]
123  set u [expr int(300)]
124  sf_execsql { SELECT sum(y) FROM t1 WHERE x>$l AND x<$u }
125} {199 0 14850}
126do_test analyze3-1.1.7 {
127  sf_execsql { SELECT sum(y) FROM t1 WHERE x>0 AND x<1100 }
128} {2000 0 499500}
129do_test analyze3-1.1.8 {
130  set l [string range "0" 0 end]
131  set u [string range "1100" 0 end]
132  sf_execsql { SELECT sum(y) FROM t1 WHERE x>$l AND x<$u }
133} {2000 0 499500}
134do_test analyze3-1.1.9 {
135  set l [expr int(0)]
136  set u [expr int(1100)]
137  sf_execsql { SELECT sum(y) FROM t1 WHERE x>$l AND x<$u }
138} {2000 0 499500}
139
140
141# The following tests are similar to the block above. The difference is
142# that the indexed column has TEXT affinity in this case. In the tests
143# above the affinity is INTEGER.
144#
145do_test analyze3-1.2.1 {
146  execsql {
147    BEGIN;
148      CREATE TABLE t2(x TEXT, y);
149      INSERT INTO t2 SELECT * FROM t1;
150      CREATE INDEX i2 ON t2(x);
151    COMMIT;
152    ANALYZE;
153  }
154} {}
155do_eqp_test analyze3-1.2.2 {
156  SELECT sum(y) FROM t2 WHERE x>1 AND x<2
157} {0 0 0 {SEARCH TABLE t2 USING INDEX i2 (x>? AND x<?)}}
158do_eqp_test analyze3-1.2.3 {
159  SELECT sum(y) FROM t2 WHERE x>0 AND x<99
160} {0 0 0 {SEARCH TABLE t2 USING INDEX i2 (x>? AND x<?)}}
161do_test analyze3-1.2.4 {
162  sf_execsql { SELECT sum(y) FROM t2 WHERE x>12 AND x<20 }
163} {161 0 4760}
164do_test analyze3-1.2.5 {
165  set l [string range "12" 0 end]
166  set u [string range "20" 0 end]
167  sf_execsql {SELECT typeof($l), typeof($u), sum(y) FROM t2 WHERE x>$l AND x<$u}
168} {161 0 text text 4760}
169do_test analyze3-1.2.6 {
170  set l [expr int(12)]
171  set u [expr int(20)]
172  sf_execsql {SELECT typeof($l), typeof($u), sum(y) FROM t2 WHERE x>$l AND x<$u}
173} {161 0 integer integer 4760}
174do_test analyze3-1.2.7 {
175  sf_execsql { SELECT sum(y) FROM t2 WHERE x>0 AND x<99 }
176} {1981 0 490555}
177do_test analyze3-1.2.8 {
178  set l [string range "0" 0 end]
179  set u [string range "99" 0 end]
180  sf_execsql {SELECT typeof($l), typeof($u), sum(y) FROM t2 WHERE x>$l AND x<$u}
181} {1981 0 text text 490555}
182do_test analyze3-1.2.9 {
183  set l [expr int(0)]
184  set u [expr int(99)]
185  sf_execsql {SELECT typeof($l), typeof($u), sum(y) FROM t2 WHERE x>$l AND x<$u}
186} {1981 0 integer integer 490555}
187
188# Same tests a third time. This time, column x has INTEGER affinity and
189# is not the leftmost column of the table. This triggered a bug causing
190# SQLite to use sub-optimal query plans in 3.6.18 and earlier.
191#
192do_test analyze3-1.3.1 {
193  execsql {
194    BEGIN;
195      CREATE TABLE t3(y TEXT, x INTEGER);
196      INSERT INTO t3 SELECT y, x FROM t1;
197      CREATE INDEX i3 ON t3(x);
198    COMMIT;
199    ANALYZE;
200  }
201} {}
202do_eqp_test analyze3-1.3.2 {
203  SELECT sum(y) FROM t3 WHERE x>200 AND x<300
204} {0 0 0 {SEARCH TABLE t3 USING INDEX i3 (x>? AND x<?)}}
205do_eqp_test analyze3-1.3.3 {
206  SELECT sum(y) FROM t3 WHERE x>0 AND x<1100
207} {0 0 0 {SEARCH TABLE t3 USING INDEX i3 (x>? AND x<?)}}
208
209do_test analyze3-1.3.4 {
210  sf_execsql { SELECT sum(y) FROM t3 WHERE x>200 AND x<300 }
211} {199 0 14850}
212do_test analyze3-1.3.5 {
213  set l [string range "200" 0 end]
214  set u [string range "300" 0 end]
215  sf_execsql { SELECT sum(y) FROM t3 WHERE x>$l AND x<$u }
216} {199 0 14850}
217do_test analyze3-1.3.6 {
218  set l [expr int(200)]
219  set u [expr int(300)]
220  sf_execsql { SELECT sum(y) FROM t3 WHERE x>$l AND x<$u }
221} {199 0 14850}
222do_test analyze3-1.3.7 {
223  sf_execsql { SELECT sum(y) FROM t3 WHERE x>0 AND x<1100 }
224} {2000 0 499500}
225do_test analyze3-1.3.8 {
226  set l [string range "0" 0 end]
227  set u [string range "1100" 0 end]
228  sf_execsql { SELECT sum(y) FROM t3 WHERE x>$l AND x<$u }
229} {2000 0 499500}
230do_test analyze3-1.3.9 {
231  set l [expr int(0)]
232  set u [expr int(1100)]
233  sf_execsql { SELECT sum(y) FROM t3 WHERE x>$l AND x<$u }
234} {2000 0 499500}
235
236#-------------------------------------------------------------------------
237# Test that the values of bound SQL variables may be used for the LIKE
238# optimization.
239#
240drop_all_tables
241do_test analyze3-2.1 {
242  execsql {
243    PRAGMA case_sensitive_like=off;
244    BEGIN;
245    CREATE TABLE t1(a, b TEXT COLLATE nocase);
246    CREATE INDEX i1 ON t1(b);
247  }
248  for {set i 0} {$i < 1000} {incr i} {
249    set t ""
250    append t [lindex {a b c d e f g h i j} [expr $i/100]]
251    append t [lindex {a b c d e f g h i j} [expr ($i/10)%10]]
252    append t [lindex {a b c d e f g h i j} [expr ($i%10)]]
253    execsql { INSERT INTO t1 VALUES($i, $t) }
254  }
255  execsql COMMIT
256} {}
257do_eqp_test analyze3-2.2 {
258  SELECT count(a) FROM t1 WHERE b LIKE 'a%'
259} {0 0 0 {SEARCH TABLE t1 USING INDEX i1 (b>? AND b<?)}}
260do_eqp_test analyze3-2.3 {
261  SELECT count(a) FROM t1 WHERE b LIKE '%a'
262} {0 0 0 {SCAN TABLE t1}}
263
264do_test analyze3-2.4 {
265  sf_execsql { SELECT count(*) FROM t1 WHERE b LIKE 'a%' }
266} {101 0 100}
267do_test analyze3-2.5 {
268  sf_execsql { SELECT count(*) FROM t1 WHERE b LIKE '%a' }
269} {999 999 100}
270
271do_test analyze3-2.4 {
272  set like "a%"
273  sf_execsql { SELECT count(*) FROM t1 WHERE b LIKE $like }
274} {101 0 100}
275do_test analyze3-2.5 {
276  set like "%a"
277  sf_execsql { SELECT count(*) FROM t1 WHERE b LIKE $like }
278} {999 999 100}
279do_test analyze3-2.6 {
280  set like "a"
281  sf_execsql { SELECT count(*) FROM t1 WHERE b LIKE $like }
282} {101 0 0}
283do_test analyze3-2.7 {
284  set like "ab"
285  sf_execsql { SELECT count(*) FROM t1 WHERE b LIKE $like }
286} {11 0 0}
287do_test analyze3-2.8 {
288  set like "abc"
289  sf_execsql { SELECT count(*) FROM t1 WHERE b LIKE $like }
290} {2 0 1}
291do_test analyze3-2.9 {
292  set like "a_c"
293  sf_execsql { SELECT count(*) FROM t1 WHERE b LIKE $like }
294} {101 0 10}
295
296
297#-------------------------------------------------------------------------
298# This block of tests checks that statements are correctly marked as
299# expired when the values bound to any parameters that may affect the
300# query plan are modified.
301#
302drop_all_tables
303db auth auth
304proc auth {args} {
305  set ::auth 1
306  return SQLITE_OK
307}
308
309do_test analyze3-3.1 {
310  execsql {
311    BEGIN;
312    CREATE TABLE t1(a, b, c);
313    CREATE INDEX i1 ON t1(b);
314  }
315  for {set i 0} {$i < 100} {incr i} {
316    execsql { INSERT INTO t1 VALUES($i, $i, $i) }
317  }
318  execsql COMMIT
319  execsql ANALYZE
320} {}
321do_test analyze3-3.2.1 {
322  set S [sqlite3_prepare_v2 db "SELECT * FROM t1 WHERE b>?" -1 dummy]
323  sqlite3_expired $S
324} {0}
325do_test analyze3-3.2.2 {
326  sqlite3_bind_text $S 1 "abc" 3
327  sqlite3_expired $S
328} {1}
329do_test analyze3-3.2.4 {
330  sqlite3_finalize $S
331} {SQLITE_OK}
332
333do_test analyze3-3.2.5 {
334  set S [sqlite3_prepare_v2 db "SELECT * FROM t1 WHERE b=?" -1 dummy]
335  sqlite3_expired $S
336} {0}
337do_test analyze3-3.2.6 {
338  sqlite3_bind_text $S 1 "abc" 3
339  sqlite3_expired $S
340} {1}
341do_test analyze3-3.2.7 {
342  sqlite3_finalize $S
343} {SQLITE_OK}
344
345do_test analyze3-3.4.1 {
346  set S [sqlite3_prepare_v2 db "SELECT * FROM t1 WHERE a=? AND b>?" -1 dummy]
347  sqlite3_expired $S
348} {0}
349do_test analyze3-3.4.2 {
350  sqlite3_bind_text $S 1 "abc" 3
351  sqlite3_expired $S
352} {0}
353do_test analyze3-3.4.3 {
354  sqlite3_bind_text $S 2 "def" 3
355  sqlite3_expired $S
356} {1}
357do_test analyze3-3.4.4 {
358  sqlite3_bind_text $S 2 "ghi" 3
359  sqlite3_expired $S
360} {1}
361do_test analyze3-3.4.5 {
362  sqlite3_expired $S
363} {1}
364do_test analyze3-3.4.6 {
365  sqlite3_finalize $S
366} {SQLITE_OK}
367
368do_test analyze3-3.5.1 {
369  set S [sqlite3_prepare_v2 db {
370    SELECT * FROM t1 WHERE a IN (
371      ?1, ?2, ?3, ?4, ?5, ?6, ?7, ?8, ?9, ?10,
372      ?11, ?12, ?13, ?14, ?15, ?16, ?17, ?18, ?19, ?20,
373      ?21, ?22, ?23, ?24, ?25, ?26, ?27, ?28, ?29, ?30, ?31
374    ) AND b>?32;
375  } -1 dummy]
376  sqlite3_expired $S
377} {0}
378do_test analyze3-3.5.2 {
379  sqlite3_bind_text $S 31 "abc" 3
380  sqlite3_expired $S
381} {0}
382do_test analyze3-3.5.3 {
383  sqlite3_bind_text $S 32 "def" 3
384  sqlite3_expired $S
385} {1}
386do_test analyze3-3.5.5 {
387  sqlite3_finalize $S
388} {SQLITE_OK}
389
390do_test analyze3-3.6.1 {
391  set S [sqlite3_prepare_v2 db {
392    SELECT * FROM t1 WHERE a IN (
393      ?1, ?2, ?3, ?4, ?5, ?6, ?7, ?8, ?9, ?10,
394      ?11, ?12, ?13, ?14, ?15, ?16, ?17, ?18, ?19, ?20,
395      ?21, ?22, ?23, ?24, ?25, ?26, ?27, ?28, ?29, ?30, ?31, ?32
396    ) AND b>?33;
397  } -1 dummy]
398  sqlite3_expired $S
399} {0}
400do_test analyze3-3.6.2 {
401  sqlite3_bind_text $S 32 "abc" 3
402  sqlite3_expired $S
403} {1}
404do_test analyze3-3.6.3 {
405  sqlite3_bind_text $S 33 "def" 3
406  sqlite3_expired $S
407} {1}
408do_test analyze3-3.6.5 {
409  sqlite3_finalize $S
410} {SQLITE_OK}
411
412do_test analyze3-3.7.1 {
413  set S [sqlite3_prepare_v2 db {
414    SELECT * FROM t1 WHERE a IN (
415      ?1, ?2, ?3, ?4, ?5, ?6, ?7, ?8, ?9, ?33,
416      ?11, ?12, ?13, ?14, ?15, ?16, ?17, ?18, ?19, ?20,
417      ?21, ?22, ?23, ?24, ?25, ?26, ?27, ?28, ?29, ?30, ?31, ?32
418    ) AND b>?10;
419  } -1 dummy]
420  sqlite3_expired $S
421} {0}
422do_test analyze3-3.7.2 {
423  sqlite3_bind_text $S 32 "abc" 3
424  sqlite3_expired $S
425} {0}
426do_test analyze3-3.7.3 {
427  sqlite3_bind_text $S 33 "def" 3
428  sqlite3_expired $S
429} {0}
430do_test analyze3-3.7.4 {
431  sqlite3_bind_text $S 10 "def" 3
432  sqlite3_expired $S
433} {1}
434do_test analyze3-3.7.6 {
435  sqlite3_finalize $S
436} {SQLITE_OK}
437
438do_test analyze3-3.8.1 {
439  execsql {
440    CREATE TABLE t4(x, y TEXT COLLATE NOCASE);
441    CREATE INDEX i4 ON t4(y);
442  }
443} {}
444do_test analyze3-3.8.2 {
445  set S [sqlite3_prepare_v2 db {
446    SELECT * FROM t4 WHERE x != ? AND y LIKE ?
447  } -1 dummy]
448  sqlite3_expired $S
449} {0}
450do_test analyze3-3.8.3 {
451  sqlite3_bind_text $S 1 "abc" 3
452  sqlite3_expired $S
453} {0}
454do_test analyze3-3.8.4 {
455  sqlite3_bind_text $S 2 "def" 3
456  sqlite3_expired $S
457} {1}
458do_test analyze3-3.8.7 {
459  sqlite3_bind_text $S 2 "ghi%" 4
460  sqlite3_expired $S
461} {1}
462do_test analyze3-3.8.8 {
463  sqlite3_expired $S
464} {1}
465do_test analyze3-3.8.9 {
466  sqlite3_bind_text $S 2 "ghi%def" 7
467  sqlite3_expired $S
468} {1}
469do_test analyze3-3.8.10 {
470  sqlite3_expired $S
471} {1}
472do_test analyze3-3.8.11 {
473  sqlite3_bind_text $S 2 "%ab" 3
474  sqlite3_expired $S
475} {1}
476do_test analyze3-3.8.12 {
477  sqlite3_expired $S
478} {1}
479do_test analyze3-3.8.12 {
480  sqlite3_bind_text $S 2 "%de" 3
481  sqlite3_expired $S
482} {1}
483do_test analyze3-3.8.13 {
484  sqlite3_expired $S
485} {1}
486do_test analyze3-3.8.14 {
487  sqlite3_finalize $S
488} {SQLITE_OK}
489
490#-------------------------------------------------------------------------
491# These tests check that errors encountered while repreparing an SQL
492# statement within sqlite3Reprepare() are handled correctly.
493#
494
495# Check a schema error.
496#
497do_test analyze3-4.1.1 {
498  set S [sqlite3_prepare_v2 db "SELECT * FROM t1 WHERE a=? AND b>?" -1 dummy]
499  sqlite3_step $S
500} {SQLITE_DONE}
501do_test analyze3-4.1.2 {
502  sqlite3_reset $S
503  sqlite3_bind_text $S 2 "abc" 3
504  execsql { DROP TABLE t1 }
505  sqlite3_step $S
506} {SQLITE_ERROR}
507do_test analyze3-4.1.3 {
508  sqlite3_finalize $S
509} {SQLITE_ERROR}
510
511# Check an authorization error.
512#
513do_test analyze3-4.2.1 {
514  execsql {
515    BEGIN;
516    CREATE TABLE t1(a, b, c);
517    CREATE INDEX i1 ON t1(b);
518  }
519  for {set i 0} {$i < 100} {incr i} {
520    execsql { INSERT INTO t1 VALUES($i, $i, $i) }
521  }
522  execsql COMMIT
523  execsql ANALYZE
524  set S [sqlite3_prepare_v2 db "SELECT * FROM t1 WHERE a=? AND b>?" -1 dummy]
525  sqlite3_step $S
526} {SQLITE_DONE}
527db auth auth
528proc auth {args} {
529  if {[lindex $args 0] == "SQLITE_READ"} {return SQLITE_DENY}
530  return SQLITE_OK
531}
532do_test analyze3-4.2.2 {
533  sqlite3_reset $S
534  sqlite3_bind_text $S 2 "abc" 3
535  sqlite3_step $S
536} {SQLITE_AUTH}
537do_test analyze3-4.2.4 {
538  sqlite3_finalize $S
539} {SQLITE_AUTH}
540
541# Check the effect of an authorization error that occurs in a re-prepare
542# performed by sqlite3_step() is the same as one that occurs within
543# sqlite3Reprepare().
544#
545do_test analyze3-4.3.1 {
546  db auth {}
547  set S [sqlite3_prepare_v2 db "SELECT * FROM t1 WHERE a=? AND b>?" -1 dummy]
548  execsql { CREATE TABLE t2(d, e, f) }
549  db auth auth
550  sqlite3_step $S
551} {SQLITE_AUTH}
552do_test analyze3-4.3.2 {
553  sqlite3_finalize $S
554} {SQLITE_AUTH}
555db auth {}
556
557#-------------------------------------------------------------------------
558# Test that modifying bound variables using the clear_bindings() or
559# transfer_bindings() APIs works.
560#
561#   analyze3-5.1.*: sqlite3_clear_bindings()
562#   analyze3-5.2.*: sqlite3_transfer_bindings()
563#
564do_test analyze3-5.1.1 {
565  drop_all_tables
566  execsql {
567    CREATE TABLE t1(x TEXT COLLATE NOCASE);
568    CREATE INDEX i1 ON t1(x);
569    INSERT INTO t1 VALUES('aaa');
570    INSERT INTO t1 VALUES('abb');
571    INSERT INTO t1 VALUES('acc');
572    INSERT INTO t1 VALUES('baa');
573    INSERT INTO t1 VALUES('bbb');
574    INSERT INTO t1 VALUES('bcc');
575  }
576
577  set S [sqlite3_prepare_v2 db "SELECT * FROM t1 WHERE x LIKE ?" -1 dummy]
578  sqlite3_bind_text $S 1 "a%" 2
579  set R [list]
580  while { "SQLITE_ROW" == [sqlite3_step $S] } {
581    lappend R [sqlite3_column_text $S 0]
582  }
583  concat [sqlite3_reset $S] $R
584} {SQLITE_OK aaa abb acc}
585do_test analyze3-5.1.2 {
586  sqlite3_clear_bindings $S
587  set R [list]
588  while { "SQLITE_ROW" == [sqlite3_step $S] } {
589    lappend R [sqlite3_column_text $S 0]
590  }
591  concat [sqlite3_reset $S] $R
592} {SQLITE_OK}
593do_test analyze3-5.1.3 {
594  sqlite3_finalize $S
595} {SQLITE_OK}
596
597do_test analyze3-5.1.1 {
598  set S1 [sqlite3_prepare_v2 db "SELECT * FROM t1 WHERE x LIKE ?" -1 dummy]
599  sqlite3_bind_text $S1 1 "b%" 2
600  set R [list]
601  while { "SQLITE_ROW" == [sqlite3_step $S1] } {
602    lappend R [sqlite3_column_text $S1 0]
603  }
604  concat [sqlite3_reset $S1] $R
605} {SQLITE_OK baa bbb bcc}
606
607do_test analyze3-5.1.2 {
608  set S2 [sqlite3_prepare_v2 db "SELECT * FROM t1 WHERE x = ?" -1 dummy]
609  sqlite3_bind_text $S2 1 "a%" 2
610  sqlite3_transfer_bindings $S2 $S1
611  set R [list]
612  while { "SQLITE_ROW" == [sqlite3_step $S1] } {
613    lappend R [sqlite3_column_text $S1 0]
614  }
615  concat [sqlite3_reset $S1] $R
616} {SQLITE_OK aaa abb acc}
617do_test analyze3-5.1.3 {
618  sqlite3_finalize $S2
619  sqlite3_finalize $S1
620} {SQLITE_OK}
621
622#-------------------------------------------------------------------------
623
624do_test analyze3-6.1 {
625  execsql { DROP TABLE IF EXISTS t1 }
626  execsql BEGIN
627  execsql { CREATE TABLE t1(a, b, c) }
628  for {set i 0} {$i < 1000} {incr i} {
629    execsql "INSERT INTO t1 VALUES([expr $i/100], 'x', [expr $i/10])"
630  }
631  execsql {
632    CREATE INDEX i1 ON t1(a, b);
633    CREATE INDEX i2 ON t1(c);
634  }
635  execsql COMMIT
636  execsql ANALYZE
637} {}
638
639do_eqp_test analyze3-6-3 {
640  SELECT * FROM t1 WHERE a = 5 AND c = 13;
641} {0 0 0 {SEARCH TABLE t1 USING INDEX i2 (c=?)}}
642
643do_eqp_test analyze3-6-2 {
644  SELECT * FROM t1 WHERE a = 5 AND b > 'w' AND c = 13;
645} {0 0 0 {SEARCH TABLE t1 USING INDEX i2 (c=?)}}
646
647finish_test
648