3 # The author disclaims copyright to this source code. In place of
4 # a legal notice, here is a blessing:
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.
10 #***********************************************************************
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.
17 set testdir [file dirname $argv0]
18 source $testdir/tester.tcl
20 ifcapable !stat4&&!stat3 {
25 #----------------------------------------------------------------------
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.
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.
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.
40 # analyze3-4.*: Test that SQL or authorization callback errors occuring
41 # within sqlite3Reprepare() are handled correctly.
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.
47 # analyze3-6.*: Test that the problem fixed by commit [127a5b776d] is fixed.
50 proc getvar {varname} { uplevel #0 set $varname }
51 db function var getvar
53 proc eqp {sql {db db}} {
54 uplevel execsql [list "EXPLAIN QUERY PLAN $sql"] $db
57 proc sf_execsql {sql {db db}} {
58 set ::sqlite_search_count 0
59 set r [uplevel [list execsql $sql $db]]
61 concat $::sqlite_search_count [$db status step] $r
64 #-------------------------------------------------------------------------
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.
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.
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.
81 # These tests also check that the compiler code considers column
82 # affinities when estimating the number of rows scanned by the "use
85 do_test analyze3-1.1.1 {
88 CREATE TABLE t1(x INTEGER, y);
89 CREATE INDEX i1 ON t1(x);
91 for {set i 0} {$i < 1000} {incr i} {
92 execsql { INSERT INTO t1 VALUES($i+100, $i) }
100 execsql { SELECT count(*)>0 FROM sqlite_stat4; }
102 execsql { SELECT count(*)>0 FROM sqlite_stat3; }
106 do_execsql_test analyze3-1.1.x {
107 SELECT count(*) FROM t1 WHERE x>200 AND x<300;
108 SELECT count(*) FROM t1 WHERE x>0 AND x<1100;
111 # The first of the following two SELECT statements visits 99 rows. So
112 # it is better to use the index. But the second visits every row in
113 # the table (1000 in total) so it is better to do a full-table scan.
115 do_eqp_test analyze3-1.1.2 {
116 SELECT sum(y) FROM t1 WHERE x>200 AND x<300
117 } {0 0 0 {SEARCH TABLE t1 USING INDEX i1 (x>? AND x<?)}}
118 do_eqp_test analyze3-1.1.3 {
119 SELECT sum(y) FROM t1 WHERE x>0 AND x<1100
120 } {0 0 0 {SCAN TABLE t1}}
122 do_test analyze3-1.1.4 {
123 sf_execsql { SELECT sum(y) FROM t1 WHERE x>200 AND x<300 }
125 do_test analyze3-1.1.5 {
126 set l [string range "200" 0 end]
127 set u [string range "300" 0 end]
128 sf_execsql { SELECT sum(y) FROM t1 WHERE x>$l AND x<$u }
130 do_test analyze3-1.1.6 {
131 set l [expr int(200)]
132 set u [expr int(300)]
133 sf_execsql { SELECT sum(y) FROM t1 WHERE x>$l AND x<$u }
135 do_test analyze3-1.1.7 {
136 sf_execsql { SELECT sum(y) FROM t1 WHERE x>0 AND x<1100 }
138 do_test analyze3-1.1.8 {
139 set l [string range "0" 0 end]
140 set u [string range "1100" 0 end]
141 sf_execsql { SELECT sum(y) FROM t1 WHERE x>$l AND x<$u }
143 do_test analyze3-1.1.9 {
145 set u [expr int(1100)]
146 sf_execsql { SELECT sum(y) FROM t1 WHERE x>$l AND x<$u }
150 # The following tests are similar to the block above. The difference is
151 # that the indexed column has TEXT affinity in this case. In the tests
152 # above the affinity is INTEGER.
154 do_test analyze3-1.2.1 {
157 CREATE TABLE t2(x TEXT, y);
158 INSERT INTO t2 SELECT * FROM t1;
159 CREATE INDEX i2 ON t2(x);
164 do_execsql_test analyze3-2.1.x {
165 SELECT count(*) FROM t2 WHERE x>1 AND x<2;
166 SELECT count(*) FROM t2 WHERE x>0 AND x<99;
168 do_eqp_test analyze3-1.2.2 {
169 SELECT sum(y) FROM t2 WHERE x>1 AND x<2
170 } {0 0 0 {SEARCH TABLE t2 USING INDEX i2 (x>? AND x<?)}}
171 do_eqp_test analyze3-1.2.3 {
172 SELECT sum(y) FROM t2 WHERE x>0 AND x<99
173 } {0 0 0 {SCAN TABLE t2}}
175 do_test analyze3-1.2.4 {
176 sf_execsql { SELECT sum(y) FROM t2 WHERE x>12 AND x<20 }
178 do_test analyze3-1.2.5 {
179 set l [string range "12" 0 end]
180 set u [string range "20" 0 end]
181 sf_execsql {SELECT typeof($l), typeof($u), sum(y) FROM t2 WHERE x>$l AND x<$u}
182 } {161 0 text text 4760}
183 do_test analyze3-1.2.6 {
186 sf_execsql {SELECT typeof($l), typeof($u), sum(y) FROM t2 WHERE x>$l AND x<$u}
187 } {161 0 integer integer 4760}
188 do_test analyze3-1.2.7 {
189 sf_execsql { SELECT sum(y) FROM t2 WHERE x>0 AND x<99 }
191 do_test analyze3-1.2.8 {
192 set l [string range "0" 0 end]
193 set u [string range "99" 0 end]
194 sf_execsql {SELECT typeof($l), typeof($u), sum(y) FROM t2 WHERE x>$l AND x<$u}
195 } {999 999 text text 490555}
196 do_test analyze3-1.2.9 {
199 sf_execsql {SELECT typeof($l), typeof($u), sum(y) FROM t2 WHERE x>$l AND x<$u}
200 } {999 999 integer integer 490555}
202 # Same tests a third time. This time, column x has INTEGER affinity and
203 # is not the leftmost column of the table. This triggered a bug causing
204 # SQLite to use sub-optimal query plans in 3.6.18 and earlier.
206 do_test analyze3-1.3.1 {
209 CREATE TABLE t3(y TEXT, x INTEGER);
210 INSERT INTO t3 SELECT y, x FROM t1;
211 CREATE INDEX i3 ON t3(x);
216 do_execsql_test analyze3-1.3.x {
217 SELECT count(*) FROM t3 WHERE x>200 AND x<300;
218 SELECT count(*) FROM t3 WHERE x>0 AND x<1100
220 do_eqp_test analyze3-1.3.2 {
221 SELECT sum(y) FROM t3 WHERE x>200 AND x<300
222 } {0 0 0 {SEARCH TABLE t3 USING INDEX i3 (x>? AND x<?)}}
223 do_eqp_test analyze3-1.3.3 {
224 SELECT sum(y) FROM t3 WHERE x>0 AND x<1100
225 } {0 0 0 {SCAN TABLE t3}}
227 do_test analyze3-1.3.4 {
228 sf_execsql { SELECT sum(y) FROM t3 WHERE x>200 AND x<300 }
230 do_test analyze3-1.3.5 {
231 set l [string range "200" 0 end]
232 set u [string range "300" 0 end]
233 sf_execsql { SELECT sum(y) FROM t3 WHERE x>$l AND x<$u }
235 do_test analyze3-1.3.6 {
236 set l [expr int(200)]
237 set u [expr int(300)]
238 sf_execsql { SELECT sum(y) FROM t3 WHERE x>$l AND x<$u }
240 do_test analyze3-1.3.7 {
241 sf_execsql { SELECT sum(y) FROM t3 WHERE x>0 AND x<1100 }
243 do_test analyze3-1.3.8 {
244 set l [string range "0" 0 end]
245 set u [string range "1100" 0 end]
246 sf_execsql { SELECT sum(y) FROM t3 WHERE x>$l AND x<$u }
248 do_test analyze3-1.3.9 {
250 set u [expr int(1100)]
251 sf_execsql { SELECT sum(y) FROM t3 WHERE x>$l AND x<$u }
254 #-------------------------------------------------------------------------
255 # Test that the values of bound SQL variables may be used for the LIKE
259 do_test analyze3-2.1 {
261 PRAGMA case_sensitive_like=off;
263 CREATE TABLE t1(a, b TEXT COLLATE nocase);
264 CREATE INDEX i1 ON t1(b);
266 for {set i 0} {$i < 1000} {incr i} {
268 append t [lindex {a b c d e f g h i j} [expr $i/100]]
269 append t [lindex {a b c d e f g h i j} [expr ($i/10)%10]]
270 append t [lindex {a b c d e f g h i j} [expr ($i%10)]]
271 execsql { INSERT INTO t1 VALUES($i, $t) }
275 do_eqp_test analyze3-2.2 {
276 SELECT count(a) FROM t1 WHERE b LIKE 'a%'
277 } {0 0 0 {SEARCH TABLE t1 USING INDEX i1 (b>? AND b<?)}}
278 do_eqp_test analyze3-2.3 {
279 SELECT count(a) FROM t1 WHERE b LIKE '%a'
280 } {0 0 0 {SCAN TABLE t1}}
282 do_test analyze3-2.4 {
283 sf_execsql { SELECT count(*) FROM t1 WHERE b LIKE 'a%' }
285 do_test analyze3-2.5 {
286 sf_execsql { SELECT count(*) FROM t1 WHERE b LIKE '%a' }
289 do_test analyze3-2.4 {
291 sf_execsql { SELECT count(*) FROM t1 WHERE b LIKE $like }
293 do_test analyze3-2.5 {
295 sf_execsql { SELECT count(*) FROM t1 WHERE b LIKE $like }
297 do_test analyze3-2.6 {
299 sf_execsql { SELECT count(*) FROM t1 WHERE b LIKE $like }
301 do_test analyze3-2.7 {
303 sf_execsql { SELECT count(*) FROM t1 WHERE b LIKE $like }
305 do_test analyze3-2.8 {
307 sf_execsql { SELECT count(*) FROM t1 WHERE b LIKE $like }
309 do_test analyze3-2.9 {
311 sf_execsql { SELECT count(*) FROM t1 WHERE b LIKE $like }
315 #-------------------------------------------------------------------------
316 # This block of tests checks that statements are correctly marked as
317 # expired when the values bound to any parameters that may affect the
318 # query plan are modified.
327 do_test analyze3-3.1 {
330 CREATE TABLE t1(a, b, c);
331 CREATE INDEX i1 ON t1(b);
333 for {set i 0} {$i < 100} {incr i} {
334 execsql { INSERT INTO t1 VALUES($i, $i, $i) }
339 do_test analyze3-3.2.1 {
340 set S [sqlite3_prepare_v2 db "SELECT * FROM t1 WHERE b>?" -1 dummy]
343 do_test analyze3-3.2.2 {
344 sqlite3_bind_text $S 1 "abc" 3
347 do_test analyze3-3.2.4 {
351 do_test analyze3-3.2.5 {
352 set S [sqlite3_prepare_v2 db "SELECT * FROM t1 WHERE b=?" -1 dummy]
355 do_test analyze3-3.2.6 {
356 sqlite3_bind_text $S 1 "abc" 3
359 do_test analyze3-3.2.7 {
363 do_test analyze3-3.4.1 {
364 set S [sqlite3_prepare_v2 db "SELECT * FROM t1 WHERE a=? AND b>?" -1 dummy]
367 do_test analyze3-3.4.2 {
368 sqlite3_bind_text $S 1 "abc" 3
371 do_test analyze3-3.4.3 {
372 sqlite3_bind_text $S 2 "def" 3
375 do_test analyze3-3.4.4 {
376 sqlite3_bind_text $S 2 "ghi" 3
379 do_test analyze3-3.4.5 {
382 do_test analyze3-3.4.6 {
386 do_test analyze3-3.5.1 {
387 set S [sqlite3_prepare_v2 db {
388 SELECT * FROM t1 WHERE a IN (
389 ?1, ?2, ?3, ?4, ?5, ?6, ?7, ?8, ?9, ?10,
390 ?11, ?12, ?13, ?14, ?15, ?16, ?17, ?18, ?19, ?20,
391 ?21, ?22, ?23, ?24, ?25, ?26, ?27, ?28, ?29, ?30, ?31
396 do_test analyze3-3.5.2 {
397 sqlite3_bind_text $S 31 "abc" 3
400 do_test analyze3-3.5.3 {
401 sqlite3_bind_text $S 32 "def" 3
404 do_test analyze3-3.5.5 {
408 do_test analyze3-3.6.1 {
409 set S [sqlite3_prepare_v2 db {
410 SELECT * FROM t1 WHERE a IN (
411 ?1, ?2, ?3, ?4, ?5, ?6, ?7, ?8, ?9, ?10,
412 ?11, ?12, ?13, ?14, ?15, ?16, ?17, ?18, ?19, ?20,
413 ?21, ?22, ?23, ?24, ?25, ?26, ?27, ?28, ?29, ?30, ?31, ?32
418 do_test analyze3-3.6.2 {
419 sqlite3_bind_text $S 32 "abc" 3
422 do_test analyze3-3.6.3 {
423 sqlite3_bind_text $S 33 "def" 3
426 do_test analyze3-3.6.5 {
430 do_test analyze3-3.7.1 {
431 set S [sqlite3_prepare_v2 db {
432 SELECT * FROM t1 WHERE a IN (
433 ?1, ?2, ?3, ?4, ?5, ?6, ?7, ?8, ?9, ?33,
434 ?11, ?12, ?13, ?14, ?15, ?16, ?17, ?18, ?19, ?20,
435 ?21, ?22, ?23, ?24, ?25, ?26, ?27, ?28, ?29, ?30, ?31, ?32
440 do_test analyze3-3.7.2 {
441 sqlite3_bind_text $S 32 "abc" 3
444 do_test analyze3-3.7.3 {
445 sqlite3_bind_text $S 33 "def" 3
448 do_test analyze3-3.7.4 {
449 sqlite3_bind_text $S 10 "def" 3
452 do_test analyze3-3.7.6 {
456 do_test analyze3-3.8.1 {
458 CREATE TABLE t4(x, y TEXT COLLATE NOCASE);
459 CREATE INDEX i4 ON t4(y);
462 do_test analyze3-3.8.2 {
463 set S [sqlite3_prepare_v2 db {
464 SELECT * FROM t4 WHERE x != ? AND y LIKE ?
468 do_test analyze3-3.8.3 {
469 sqlite3_bind_text $S 1 "abc" 3
472 do_test analyze3-3.8.4 {
473 sqlite3_bind_text $S 2 "def" 3
476 do_test analyze3-3.8.7 {
477 sqlite3_bind_text $S 2 "ghi%" 4
480 do_test analyze3-3.8.8 {
483 do_test analyze3-3.8.9 {
484 sqlite3_bind_text $S 2 "ghi%def" 7
487 do_test analyze3-3.8.10 {
490 do_test analyze3-3.8.11 {
491 sqlite3_bind_text $S 2 "%ab" 3
494 do_test analyze3-3.8.12 {
497 do_test analyze3-3.8.12 {
498 sqlite3_bind_text $S 2 "%de" 3
501 do_test analyze3-3.8.13 {
504 do_test analyze3-3.8.14 {
508 #-------------------------------------------------------------------------
509 # These tests check that errors encountered while repreparing an SQL
510 # statement within sqlite3Reprepare() are handled correctly.
513 # Check a schema error.
515 do_test analyze3-4.1.1 {
516 set S [sqlite3_prepare_v2 db "SELECT * FROM t1 WHERE a=? AND b>?" -1 dummy]
519 do_test analyze3-4.1.2 {
521 sqlite3_bind_text $S 2 "abc" 3
522 execsql { DROP TABLE t1 }
525 do_test analyze3-4.1.3 {
529 # Check an authorization error.
531 do_test analyze3-4.2.1 {
534 CREATE TABLE t1(a, b, c);
535 CREATE INDEX i1 ON t1(b);
537 for {set i 0} {$i < 100} {incr i} {
538 execsql { INSERT INTO t1 VALUES($i, $i, $i) }
542 set S [sqlite3_prepare_v2 db "SELECT * FROM t1 WHERE a=? AND b>?" -1 dummy]
547 if {[lindex $args 0] == "SQLITE_READ"} {return SQLITE_DENY}
550 do_test analyze3-4.2.2 {
552 sqlite3_bind_text $S 2 "abc" 3
555 do_test analyze3-4.2.4 {
559 # Check the effect of an authorization error that occurs in a re-prepare
560 # performed by sqlite3_step() is the same as one that occurs within
561 # sqlite3Reprepare().
563 do_test analyze3-4.3.1 {
565 set S [sqlite3_prepare_v2 db "SELECT * FROM t1 WHERE a=? AND b>?" -1 dummy]
566 execsql { CREATE TABLE t2(d, e, f) }
570 do_test analyze3-4.3.2 {
575 #-------------------------------------------------------------------------
576 # Test that modifying bound variables using the clear_bindings() or
577 # transfer_bindings() APIs works.
579 # analyze3-5.1.*: sqlite3_clear_bindings()
580 # analyze3-5.2.*: sqlite3_transfer_bindings()
582 do_test analyze3-5.1.1 {
585 CREATE TABLE t1(x TEXT COLLATE NOCASE);
586 CREATE INDEX i1 ON t1(x);
587 INSERT INTO t1 VALUES('aaa');
588 INSERT INTO t1 VALUES('abb');
589 INSERT INTO t1 VALUES('acc');
590 INSERT INTO t1 VALUES('baa');
591 INSERT INTO t1 VALUES('bbb');
592 INSERT INTO t1 VALUES('bcc');
595 set S [sqlite3_prepare_v2 db "SELECT * FROM t1 WHERE x LIKE ?" -1 dummy]
596 sqlite3_bind_text $S 1 "a%" 2
598 while { "SQLITE_ROW" == [sqlite3_step $S] } {
599 lappend R [sqlite3_column_text $S 0]
601 concat [sqlite3_reset $S] $R
602 } {SQLITE_OK aaa abb acc}
603 do_test analyze3-5.1.2 {
604 sqlite3_clear_bindings $S
606 while { "SQLITE_ROW" == [sqlite3_step $S] } {
607 lappend R [sqlite3_column_text $S 0]
609 concat [sqlite3_reset $S] $R
611 do_test analyze3-5.1.3 {
615 do_test analyze3-5.1.1 {
616 set S1 [sqlite3_prepare_v2 db "SELECT * FROM t1 WHERE x LIKE ?" -1 dummy]
617 sqlite3_bind_text $S1 1 "b%" 2
619 while { "SQLITE_ROW" == [sqlite3_step $S1] } {
620 lappend R [sqlite3_column_text $S1 0]
622 concat [sqlite3_reset $S1] $R
623 } {SQLITE_OK baa bbb bcc}
625 do_test analyze3-5.1.2 {
626 set S2 [sqlite3_prepare_v2 db "SELECT * FROM t1 WHERE x = ?" -1 dummy]
627 sqlite3_bind_text $S2 1 "a%" 2
628 sqlite3_transfer_bindings $S2 $S1
630 while { "SQLITE_ROW" == [sqlite3_step $S1] } {
631 lappend R [sqlite3_column_text $S1 0]
633 concat [sqlite3_reset $S1] $R
634 } {SQLITE_OK aaa abb acc}
635 do_test analyze3-5.1.3 {
640 #-------------------------------------------------------------------------
642 do_test analyze3-6.1 {
643 execsql { DROP TABLE IF EXISTS t1 }
645 execsql { CREATE TABLE t1(a, b, c) }
646 for {set i 0} {$i < 1000} {incr i} {
647 execsql "INSERT INTO t1 VALUES([expr $i/100], 'x', [expr $i/10])"
650 CREATE INDEX i1 ON t1(a, b);
651 CREATE INDEX i2 ON t1(c);
657 do_eqp_test analyze3-6-3 {
658 SELECT * FROM t1 WHERE a = 5 AND c = 13;
659 } {0 0 0 {SEARCH TABLE t1 USING INDEX i2 (c=?)}}
661 do_eqp_test analyze3-6-2 {
662 SELECT * FROM t1 WHERE a = 5 AND b > 'w' AND c = 13;
663 } {0 0 0 {SEARCH TABLE t1 USING INDEX i2 (c=?)}}