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