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