blob: 0a0533506ad2b6787337045fe9a5b26e560cb985 [file] [log] [blame]
drha6110402005-07-28 20:51:19 +00001# 2005 July 28
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# This file implements regression tests for SQLite library. The
12# focus of this file is testing the use of indices in WHERE clauses
13# based on recent changes to the optimizer.
14#
drh9373b012009-02-02 01:50:39 +000015# $Id: where2.test,v 1.15 2009/02/02 01:50:40 drh Exp $
drha6110402005-07-28 20:51:19 +000016
17set testdir [file dirname $argv0]
18source $testdir/tester.tcl
19
20# Build some test data
21#
22do_test where2-1.0 {
23 execsql {
24 BEGIN;
25 CREATE TABLE t1(w int, x int, y int, z int);
26 }
27 for {set i 1} {$i<=100} {incr i} {
28 set w $i
29 set x [expr {int(log($i)/log(2))}]
30 set y [expr {$i*$i + 2*$i + 1}]
31 set z [expr {$x+$y}]
danielk19773bdca9c2006-01-17 09:35:01 +000032 ifcapable tclvar {
33 execsql {INSERT INTO t1 VALUES($::w,$::x,$::y,$::z)}
34 } else {
35 execsql {INSERT INTO t1 VALUES(:w,:x,:y,:z)}
36 }
drha6110402005-07-28 20:51:19 +000037 }
38 execsql {
39 CREATE UNIQUE INDEX i1w ON t1(w);
40 CREATE INDEX i1xy ON t1(x,y);
41 CREATE INDEX i1zyx ON t1(z,y,x);
42 COMMIT;
43 }
44} {}
45
46# Do an SQL statement. Append the search count to the end of the result.
47#
48proc count sql {
49 set ::sqlite_search_count 0
50 return [concat [execsql $sql] $::sqlite_search_count]
51}
52
53# This procedure executes the SQL. Then it checks to see if the OP_Sort
54# opcode was executed. If an OP_Sort did occur, then "sort" is appended
55# to the result. If no OP_Sort happened, then "nosort" is appended.
56#
57# This procedure is used to check to make sure sorting is or is not
58# occurring as expected.
59#
60proc cksort {sql} {
drha6110402005-07-28 20:51:19 +000061 set data [execsql $sql]
drhd1d38482008-10-07 23:46:38 +000062 if {[db status sort]} {set x sort} {set x nosort}
drha6110402005-07-28 20:51:19 +000063 lappend data $x
64 return $data
65}
66
67# This procedure executes the SQL. Then it appends to the result the
68# "sort" or "nosort" keyword (as in the cksort procedure above) then
drh7c171092013-06-03 22:08:20 +000069# it appends the name of the table and index used.
drha6110402005-07-28 20:51:19 +000070#
71proc queryplan {sql} {
72 set ::sqlite_sort_count 0
73 set data [execsql $sql]
74 if {$::sqlite_sort_count} {set x sort} {set x nosort}
75 lappend data $x
drhae70cf12013-05-31 15:18:46 +000076 set eqp [execsql "EXPLAIN QUERY PLAN $sql"]
77 # puts eqp=$eqp
78 foreach {a b c x} $eqp {
drh8a4380d2013-06-11 02:32:50 +000079 if {[regexp { TABLE (\w+ AS )?(\w+) USING.* INDEX (\w+)\y} \
drhae70cf12013-05-31 15:18:46 +000080 $x all as tab idx]} {
81 lappend data $tab $idx
drh8a4380d2013-06-11 02:32:50 +000082 } elseif {[regexp { TABLE (\w+ AS )?(\w+)\y} $x all as tab]} {
drhae70cf12013-05-31 15:18:46 +000083 lappend data $tab *
84 }
85 }
86 return $data
drha6110402005-07-28 20:51:19 +000087}
88
89
90# Prefer a UNIQUE index over another index.
91#
92do_test where2-1.1 {
93 queryplan {
94 SELECT * FROM t1 WHERE w=85 AND x=6 AND y=7396
95 }
96} {85 6 7396 7402 nosort t1 i1w}
97
98# Always prefer a rowid== constraint over any other index.
99#
100do_test where2-1.3 {
101 queryplan {
102 SELECT * FROM t1 WHERE w=85 AND x=6 AND y=7396 AND rowid=85
103 }
104} {85 6 7396 7402 nosort t1 *}
105
106# When constrained by a UNIQUE index, the ORDER BY clause is always ignored.
107#
108do_test where2-2.1 {
109 queryplan {
drh9373b012009-02-02 01:50:39 +0000110 SELECT * FROM t1 WHERE w=85 ORDER BY random();
drha6110402005-07-28 20:51:19 +0000111 }
112} {85 6 7396 7402 nosort t1 i1w}
113do_test where2-2.2 {
114 queryplan {
drh9373b012009-02-02 01:50:39 +0000115 SELECT * FROM t1 WHERE x=6 AND y=7396 ORDER BY random();
drha6110402005-07-28 20:51:19 +0000116 }
117} {85 6 7396 7402 sort t1 i1xy}
118do_test where2-2.3 {
119 queryplan {
drh9373b012009-02-02 01:50:39 +0000120 SELECT * FROM t1 WHERE rowid=85 AND x=6 AND y=7396 ORDER BY random();
drha6110402005-07-28 20:51:19 +0000121 }
122} {85 6 7396 7402 nosort t1 *}
123
drh434a9312014-02-26 02:26:09 +0000124# Ticket [65bdeb9739605cc22966f49208452996ff29a640] 2014-02-26
125# Make sure "ORDER BY random" does not gets optimized out.
126#
127do_test where2-2.4 {
128 db eval {
129 CREATE TABLE x1(a INTEGER PRIMARY KEY, b DEFAULT 1);
130 WITH RECURSIVE
131 cnt(x) AS (VALUES(1) UNION ALL SELECT x+1 FROM cnt WHERE x<50)
132 INSERT INTO x1 SELECT x, 1 FROM cnt;
133 CREATE TABLE x2(x INTEGER PRIMARY KEY);
134 INSERT INTO x2 VALUES(1);
135 }
136 set sql {SELECT * FROM x1, x2 WHERE x=1 ORDER BY random()}
137 set out1 [db eval $sql]
138 set out2 [db eval $sql]
139 set out3 [db eval $sql]
140 expr {$out1!=$out2 && $out2!=$out3}
141} {1}
142do_execsql_test where2-2.5 {
143 -- random() is not optimized out
144 EXPLAIN SELECT * FROM x1, x2 WHERE x=1 ORDER BY random();
145} {/ random/}
146do_execsql_test where2-2.5b {
147 -- random() is not optimized out
148 EXPLAIN SELECT * FROM x1, x2 WHERE x=1 ORDER BY random();
149} {/ SorterOpen /}
150do_execsql_test where2-2.6 {
151 -- other constant functions are optimized out
152 EXPLAIN SELECT * FROM x1, x2 WHERE x=1 ORDER BY abs(5);
153} {~/ abs/}
154do_execsql_test where2-2.6b {
155 -- other constant functions are optimized out
156 EXPLAIN SELECT * FROM x1, x2 WHERE x=1 ORDER BY abs(5);
157} {~/ SorterOpen /}
158
159
drha6110402005-07-28 20:51:19 +0000160
161# Efficient handling of forward and reverse table scans.
162#
163do_test where2-3.1 {
164 queryplan {
165 SELECT * FROM t1 ORDER BY rowid LIMIT 2
166 }
167} {1 0 4 4 2 1 9 10 nosort t1 *}
168do_test where2-3.2 {
169 queryplan {
170 SELECT * FROM t1 ORDER BY rowid DESC LIMIT 2
171 }
172} {100 6 10201 10207 99 6 10000 10006 nosort t1 *}
173
174# The IN operator can be used by indices at multiple layers
175#
danielk19771576cd92006-01-14 08:02:28 +0000176ifcapable subquery {
177 do_test where2-4.1 {
178 queryplan {
179 SELECT * FROM t1 WHERE z IN (10207,10006) AND y IN (10000,10201)
180 AND x>0 AND x<10
181 ORDER BY w
182 }
183 } {99 6 10000 10006 100 6 10201 10207 sort t1 i1zyx}
184 do_test where2-4.2 {
185 queryplan {
186 SELECT * FROM t1 WHERE z IN (10207,10006) AND y=10000
187 AND x>0 AND x<10
188 ORDER BY w
189 }
190 } {99 6 10000 10006 sort t1 i1zyx}
191 do_test where2-4.3 {
192 queryplan {
193 SELECT * FROM t1 WHERE z=10006 AND y IN (10000,10201)
194 AND x>0 AND x<10
195 ORDER BY w
196 }
197 } {99 6 10000 10006 sort t1 i1zyx}
danielk1977ff890792006-01-16 16:24:25 +0000198 ifcapable compound {
199 do_test where2-4.4 {
200 queryplan {
201 SELECT * FROM t1 WHERE z IN (SELECT 10207 UNION SELECT 10006)
202 AND y IN (10000,10201)
203 AND x>0 AND x<10
204 ORDER BY w
205 }
206 } {99 6 10000 10006 100 6 10201 10207 sort t1 i1zyx}
207 do_test where2-4.5 {
208 queryplan {
209 SELECT * FROM t1 WHERE z IN (SELECT 10207 UNION SELECT 10006)
210 AND y IN (SELECT 10000 UNION SELECT 10201)
211 AND x>0 AND x<10
212 ORDER BY w
213 }
214 } {99 6 10000 10006 100 6 10201 10207 sort t1 i1zyx}
215 }
drh1b8fc652013-02-07 21:15:14 +0000216 do_test where2-4.6a {
danielk19771576cd92006-01-14 08:02:28 +0000217 queryplan {
218 SELECT * FROM t1
219 WHERE x IN (1,2,3,4,5,6,7,8)
220 AND y IN (10000,10001,10002,10003,10004,10005)
drh1b8fc652013-02-07 21:15:14 +0000221 ORDER BY x
222 }
223 } {99 6 10000 10006 nosort t1 i1xy}
224 do_test where2-4.6b {
225 queryplan {
226 SELECT * FROM t1
227 WHERE x IN (1,2,3,4,5,6,7,8)
228 AND y IN (10000,10001,10002,10003,10004,10005)
229 ORDER BY x DESC
230 }
drh2d96b932013-02-08 18:48:23 +0000231 } {99 6 10000 10006 nosort t1 i1xy}
drh1b8fc652013-02-07 21:15:14 +0000232 do_test where2-4.6c {
233 queryplan {
234 SELECT * FROM t1
235 WHERE x IN (1,2,3,4,5,6,7,8)
236 AND y IN (10000,10001,10002,10003,10004,10005)
237 ORDER BY x, y
238 }
239 } {99 6 10000 10006 nosort t1 i1xy}
240 do_test where2-4.6d {
241 queryplan {
242 SELECT * FROM t1
243 WHERE x IN (1,2,3,4,5,6,7,8)
244 AND y IN (10000,10001,10002,10003,10004,10005)
245 ORDER BY x, y DESC
danielk19771576cd92006-01-14 08:02:28 +0000246 }
247 } {99 6 10000 10006 sort t1 i1xy}
drha6110402005-07-28 20:51:19 +0000248
danielk19771576cd92006-01-14 08:02:28 +0000249 # Duplicate entires on the RHS of an IN operator do not cause duplicate
250 # output rows.
251 #
drh1b8fc652013-02-07 21:15:14 +0000252 do_test where2-4.6x {
danielk19771576cd92006-01-14 08:02:28 +0000253 queryplan {
254 SELECT * FROM t1 WHERE z IN (10207,10006,10006,10207)
255 ORDER BY w
256 }
257 } {99 6 10000 10006 100 6 10201 10207 sort t1 i1zyx}
drh1b8fc652013-02-07 21:15:14 +0000258 do_test where2-4.6y {
259 queryplan {
260 SELECT * FROM t1 WHERE z IN (10207,10006,10006,10207)
261 ORDER BY w DESC
262 }
263 } {100 6 10201 10207 99 6 10000 10006 sort t1 i1zyx}
danielk1977ff890792006-01-16 16:24:25 +0000264 ifcapable compound {
265 do_test where2-4.7 {
266 queryplan {
267 SELECT * FROM t1 WHERE z IN (
268 SELECT 10207 UNION ALL SELECT 10006
269 UNION ALL SELECT 10006 UNION ALL SELECT 10207)
270 ORDER BY w
271 }
272 } {99 6 10000 10006 100 6 10201 10207 sort t1 i1zyx}
273 }
danielk19771576cd92006-01-14 08:02:28 +0000274
275} ;# ifcapable subquery
drha6110402005-07-28 20:51:19 +0000276
277# The use of an IN operator disables the index as a sorter.
278#
279do_test where2-5.1 {
280 queryplan {
281 SELECT * FROM t1 WHERE w=99 ORDER BY w
282 }
283} {99 6 10000 10006 nosort t1 i1w}
danielk19771576cd92006-01-14 08:02:28 +0000284
285ifcapable subquery {
drh1b8fc652013-02-07 21:15:14 +0000286 do_test where2-5.2a {
danielk19771576cd92006-01-14 08:02:28 +0000287 queryplan {
288 SELECT * FROM t1 WHERE w IN (99) ORDER BY w
289 }
drh1b8fc652013-02-07 21:15:14 +0000290 } {99 6 10000 10006 nosort t1 i1w}
291 do_test where2-5.2b {
292 queryplan {
293 SELECT * FROM t1 WHERE w IN (99) ORDER BY w DESC
294 }
drh2d96b932013-02-08 18:48:23 +0000295 } {99 6 10000 10006 nosort t1 i1w}
danielk19771576cd92006-01-14 08:02:28 +0000296}
drha6110402005-07-28 20:51:19 +0000297
drh6c30be82005-07-29 15:10:17 +0000298# Verify that OR clauses get translated into IN operators.
299#
danielk19771576cd92006-01-14 08:02:28 +0000300set ::idx {}
301ifcapable subquery {set ::idx i1w}
drh3e355802007-02-23 23:13:33 +0000302do_test where2-6.1.1 {
drh6c30be82005-07-29 15:10:17 +0000303 queryplan {
304 SELECT * FROM t1 WHERE w=99 OR w=100 ORDER BY +w
305 }
danielk19771576cd92006-01-14 08:02:28 +0000306} [list 99 6 10000 10006 100 6 10201 10207 sort t1 $::idx]
drh3e355802007-02-23 23:13:33 +0000307do_test where2-6.1.2 {
308 queryplan {
309 SELECT * FROM t1 WHERE 99=w OR 100=w ORDER BY +w
310 }
311} [list 99 6 10000 10006 100 6 10201 10207 sort t1 $::idx]
drh6c30be82005-07-29 15:10:17 +0000312do_test where2-6.2 {
313 queryplan {
314 SELECT * FROM t1 WHERE w=99 OR w=100 OR 6=w ORDER BY +w
315 }
danielk19771576cd92006-01-14 08:02:28 +0000316} [list 6 2 49 51 99 6 10000 10006 100 6 10201 10207 sort t1 $::idx]
317
drh6c30be82005-07-29 15:10:17 +0000318do_test where2-6.3 {
319 queryplan {
320 SELECT * FROM t1 WHERE w=99 OR w=100 OR 6=+w ORDER BY +w
321 }
drh4fe425a2013-06-12 17:08:06 +0000322} {6 2 49 51 99 6 10000 10006 100 6 10201 10207 sort t1 *}
drh6c30be82005-07-29 15:10:17 +0000323do_test where2-6.4 {
324 queryplan {
drh2dc29292015-08-27 23:18:55 +0000325 SELECT *, '|' FROM t1 WHERE w=99 OR +w=100 OR 6=w ORDER BY +w
drh6c30be82005-07-29 15:10:17 +0000326 }
drh2dc29292015-08-27 23:18:55 +0000327} {6 2 49 51 | 99 6 10000 10006 | 100 6 10201 10207 | sort t1 *}
328do_test where2-6.5 {
329 queryplan {
330 SELECT *, '|' FROM t1 WHERE w=99 OR y=10201 OR 6=w ORDER BY +w
331 }
332} {6 2 49 51 | 99 6 10000 10006 | 100 6 10201 10207 | sort t1 *}
danielk19771576cd92006-01-14 08:02:28 +0000333
334set ::idx {}
335ifcapable subquery {set ::idx i1zyx}
drh6c30be82005-07-29 15:10:17 +0000336do_test where2-6.5 {
337 queryplan {
338 SELECT b.* FROM t1 a, t1 b
339 WHERE a.w=1 AND (a.y=b.z OR b.z=10)
340 ORDER BY +b.w
341 }
danielk19771576cd92006-01-14 08:02:28 +0000342} [list 1 0 4 4 2 1 9 10 sort a i1w b $::idx]
drh6c30be82005-07-29 15:10:17 +0000343do_test where2-6.6 {
344 queryplan {
345 SELECT b.* FROM t1 a, t1 b
346 WHERE a.w=1 AND (b.z=10 OR a.y=b.z OR b.z=10)
347 ORDER BY +b.w
348 }
danielk19771576cd92006-01-14 08:02:28 +0000349} [list 1 0 4 4 2 1 9 10 sort a i1w b $::idx]
drh6c30be82005-07-29 15:10:17 +0000350
danc1f19f92013-07-05 19:16:58 +0000351if {[permutation] != "no_optimization"} {
352
drh3e355802007-02-23 23:13:33 +0000353# Ticket #2249. Make sure the OR optimization is not attempted if
354# comparisons between columns of different affinities are needed.
355#
356do_test where2-6.7 {
357 execsql {
drh165674d2013-10-04 15:58:59 +0000358 CREATE TABLE t2249a(a TEXT UNIQUE, x CHAR(100));
drh3e355802007-02-23 23:13:33 +0000359 CREATE TABLE t2249b(b INTEGER);
drh165674d2013-10-04 15:58:59 +0000360 INSERT INTO t2249a(a) VALUES('0123');
drh3e355802007-02-23 23:13:33 +0000361 INSERT INTO t2249b VALUES(123);
362 }
363 queryplan {
364 -- Because a is type TEXT and b is type INTEGER, both a and b
365 -- will attempt to convert to NUMERIC before the comparison.
366 -- They will thus compare equal.
367 --
drh165674d2013-10-04 15:58:59 +0000368 SELECT b,a FROM t2249b CROSS JOIN t2249a WHERE a=b;
drh3e355802007-02-23 23:13:33 +0000369 }
drh4fe425a2013-06-12 17:08:06 +0000370} {123 0123 nosort t2249b * t2249a sqlite_autoindex_t2249a_1}
drh3e355802007-02-23 23:13:33 +0000371do_test where2-6.9 {
372 queryplan {
373 -- The + operator removes affinity from the rhs. No conversions
374 -- occur and the comparison is false. The result is an empty set.
375 --
drh165674d2013-10-04 15:58:59 +0000376 SELECT b,a FROM t2249b CROSS JOIN t2249a WHERE a=+b;
drh3e355802007-02-23 23:13:33 +0000377 }
drh4fe425a2013-06-12 17:08:06 +0000378} {nosort t2249b * t2249a sqlite_autoindex_t2249a_1}
drh3e355802007-02-23 23:13:33 +0000379do_test where2-6.9.2 {
380 # The same thing but with the expression flipped around.
381 queryplan {
drh165674d2013-10-04 15:58:59 +0000382 SELECT b,a FROM t2249b CROSS JOIN t2249a WHERE +b=a
drh3e355802007-02-23 23:13:33 +0000383 }
drh4fe425a2013-06-12 17:08:06 +0000384} {nosort t2249b * t2249a sqlite_autoindex_t2249a_1}
drh3e355802007-02-23 23:13:33 +0000385do_test where2-6.10 {
386 queryplan {
387 -- Use + on both sides of the comparison to disable indices
388 -- completely. Make sure we get the same result.
389 --
drh165674d2013-10-04 15:58:59 +0000390 SELECT b,a FROM t2249b CROSS JOIN t2249a WHERE +a=+b;
drh3e355802007-02-23 23:13:33 +0000391 }
drh4fe425a2013-06-12 17:08:06 +0000392} {nosort t2249b * t2249a sqlite_autoindex_t2249a_1}
drh3e355802007-02-23 23:13:33 +0000393do_test where2-6.11 {
394 # This will not attempt the OR optimization because of the a=b
395 # comparison.
396 queryplan {
drh165674d2013-10-04 15:58:59 +0000397 SELECT b,a FROM t2249b CROSS JOIN t2249a WHERE a=b OR a='hello';
drh3e355802007-02-23 23:13:33 +0000398 }
drh4fe425a2013-06-12 17:08:06 +0000399} {123 0123 nosort t2249b * t2249a sqlite_autoindex_t2249a_1}
drh3e355802007-02-23 23:13:33 +0000400do_test where2-6.11.2 {
401 # Permutations of the expression terms.
402 queryplan {
drh165674d2013-10-04 15:58:59 +0000403 SELECT b,a FROM t2249b CROSS JOIN t2249a WHERE b=a OR a='hello';
drh3e355802007-02-23 23:13:33 +0000404 }
drh4fe425a2013-06-12 17:08:06 +0000405} {123 0123 nosort t2249b * t2249a sqlite_autoindex_t2249a_1}
drh3e355802007-02-23 23:13:33 +0000406do_test where2-6.11.3 {
407 # Permutations of the expression terms.
408 queryplan {
drh165674d2013-10-04 15:58:59 +0000409 SELECT b,a FROM t2249b CROSS JOIN t2249a WHERE 'hello'=a OR b=a;
drh3e355802007-02-23 23:13:33 +0000410 }
drh4fe425a2013-06-12 17:08:06 +0000411} {123 0123 nosort t2249b * t2249a sqlite_autoindex_t2249a_1}
drh3e355802007-02-23 23:13:33 +0000412do_test where2-6.11.4 {
413 # Permutations of the expression terms.
414 queryplan {
drh165674d2013-10-04 15:58:59 +0000415 SELECT b,a FROM t2249b CROSS JOIN t2249a WHERE a='hello' OR b=a;
drh3e355802007-02-23 23:13:33 +0000416 }
drh4fe425a2013-06-12 17:08:06 +0000417} {123 0123 nosort t2249b * t2249a sqlite_autoindex_t2249a_1}
danielk1977284f4ac2007-12-10 05:03:46 +0000418ifcapable explain&&subquery {
419 # These tests are not run if subquery support is not included in the
420 # build. This is because these tests test the "a = 1 OR a = 2" to
421 # "a IN (1, 2)" optimisation transformation, which is not enabled if
422 # subqueries and the IN operator is not available.
423 #
danielk19774152e672007-09-12 17:01:45 +0000424 do_test where2-6.12 {
425 # In this case, the +b disables the affinity conflict and allows
426 # the OR optimization to be used again. The result is now an empty
427 # set, the same as in where2-6.9.
428 queryplan {
drh165674d2013-10-04 15:58:59 +0000429 SELECT b,a FROM t2249b CROSS JOIN t2249a WHERE a=+b OR a='hello';
danielk19774152e672007-09-12 17:01:45 +0000430 }
drh4fe425a2013-06-12 17:08:06 +0000431 } {nosort t2249b * t2249a sqlite_autoindex_t2249a_1}
danielk19774152e672007-09-12 17:01:45 +0000432 do_test where2-6.12.2 {
433 # In this case, the +b disables the affinity conflict and allows
434 # the OR optimization to be used again. The result is now an empty
435 # set, the same as in where2-6.9.
436 queryplan {
drh165674d2013-10-04 15:58:59 +0000437 SELECT b,a FROM t2249b CROSS JOIN t2249a WHERE a='hello' OR +b=a;
danielk19774152e672007-09-12 17:01:45 +0000438 }
drh4fe425a2013-06-12 17:08:06 +0000439 } {nosort t2249b * t2249a sqlite_autoindex_t2249a_1}
danielk19774152e672007-09-12 17:01:45 +0000440 do_test where2-6.12.3 {
441 # In this case, the +b disables the affinity conflict and allows
442 # the OR optimization to be used again. The result is now an empty
443 # set, the same as in where2-6.9.
444 queryplan {
drh165674d2013-10-04 15:58:59 +0000445 SELECT b,a FROM t2249b CROSS JOIN t2249a WHERE +b=a OR a='hello';
danielk19774152e672007-09-12 17:01:45 +0000446 }
drh4fe425a2013-06-12 17:08:06 +0000447 } {nosort t2249b * t2249a sqlite_autoindex_t2249a_1}
danielk19774152e672007-09-12 17:01:45 +0000448 do_test where2-6.13 {
449 # The addition of +a on the second term disabled the OR optimization.
450 # But we should still get the same empty-set result as in where2-6.9.
451 queryplan {
drh165674d2013-10-04 15:58:59 +0000452 SELECT b,a FROM t2249b CROSS JOIN t2249a WHERE a=+b OR +a='hello';
danielk19774152e672007-09-12 17:01:45 +0000453 }
drh4fe425a2013-06-12 17:08:06 +0000454 } {nosort t2249b * t2249a sqlite_autoindex_t2249a_1}
danielk19774152e672007-09-12 17:01:45 +0000455}
drh3e355802007-02-23 23:13:33 +0000456
457# Variations on the order of terms in a WHERE clause in order
458# to make sure the OR optimizer can recognize them all.
459do_test where2-6.20 {
460 queryplan {
drh165674d2013-10-04 15:58:59 +0000461 SELECT x.a, y.a FROM t2249a x CROSS JOIN t2249a y WHERE x.a=y.a
drh3e355802007-02-23 23:13:33 +0000462 }
drh4fe425a2013-06-12 17:08:06 +0000463} {0123 0123 nosort x sqlite_autoindex_t2249a_1 y sqlite_autoindex_t2249a_1}
danielk1977284f4ac2007-12-10 05:03:46 +0000464ifcapable explain&&subquery {
465 # These tests are not run if subquery support is not included in the
466 # build. This is because these tests test the "a = 1 OR a = 2" to
467 # "a IN (1, 2)" optimisation transformation, which is not enabled if
468 # subqueries and the IN operator is not available.
469 #
danielk19774152e672007-09-12 17:01:45 +0000470 do_test where2-6.21 {
471 queryplan {
drh165674d2013-10-04 15:58:59 +0000472 SELECT x.a,y.a FROM t2249a x CROSS JOIN t2249a y
473 WHERE x.a=y.a OR y.a='hello'
danielk19774152e672007-09-12 17:01:45 +0000474 }
drh4fe425a2013-06-12 17:08:06 +0000475 } {0123 0123 nosort x sqlite_autoindex_t2249a_1 y sqlite_autoindex_t2249a_1}
danielk19774152e672007-09-12 17:01:45 +0000476 do_test where2-6.22 {
477 queryplan {
drh165674d2013-10-04 15:58:59 +0000478 SELECT x.a,y.a FROM t2249a x CROSS JOIN t2249a y
479 WHERE y.a=x.a OR y.a='hello'
danielk19774152e672007-09-12 17:01:45 +0000480 }
drh4fe425a2013-06-12 17:08:06 +0000481 } {0123 0123 nosort x sqlite_autoindex_t2249a_1 y sqlite_autoindex_t2249a_1}
danielk19774152e672007-09-12 17:01:45 +0000482 do_test where2-6.23 {
483 queryplan {
drh165674d2013-10-04 15:58:59 +0000484 SELECT x.a,y.a FROM t2249a x CROSS JOIN t2249a y
485 WHERE y.a='hello' OR x.a=y.a
danielk19774152e672007-09-12 17:01:45 +0000486 }
drh4fe425a2013-06-12 17:08:06 +0000487 } {0123 0123 nosort x sqlite_autoindex_t2249a_1 y sqlite_autoindex_t2249a_1}
danielk19774152e672007-09-12 17:01:45 +0000488}
drh3e355802007-02-23 23:13:33 +0000489
drh8718f522005-08-13 16:13:04 +0000490# Unique queries (queries that are guaranteed to return only a single
491# row of result) do not call the sorter. But all tables must give
492# a unique result. If any one table in the join does not give a unique
493# result then sorting is necessary.
494#
495do_test where2-7.1 {
496 cksort {
497 create table t8(a unique, b, c);
498 insert into t8 values(1,2,3);
499 insert into t8 values(2,3,4);
500 create table t9(x,y);
501 insert into t9 values(2,4);
502 insert into t9 values(2,3);
503 select y from t8, t9 where a=1 order by a, y;
504 }
505} {3 4 sort}
506do_test where2-7.2 {
507 cksort {
508 select * from t8 where a=1 order by b, c
509 }
510} {1 2 3 nosort}
511do_test where2-7.3 {
512 cksort {
513 select * from t8, t9 where a=1 and y=3 order by b, x
514 }
515} {1 2 3 2 3 sort}
516do_test where2-7.4 {
517 cksort {
518 create unique index i9y on t9(y);
519 select * from t8, t9 where a=1 and y=3 order by b, x
520 }
521} {1 2 3 2 3 nosort}
drha6110402005-07-28 20:51:19 +0000522
danc1f19f92013-07-05 19:16:58 +0000523} ;# if {[permutation] != "no_optimization"}
524
drhffe0f892006-05-11 13:26:25 +0000525# Ticket #1807. Using IN constrains on multiple columns of
526# a multi-column index.
527#
528ifcapable subquery {
529 do_test where2-8.1 {
530 execsql {
531 SELECT * FROM t1 WHERE x IN (20,21) AND y IN (1,2)
532 }
533 } {}
534 do_test where2-8.2 {
535 execsql {
536 SELECT * FROM t1 WHERE x IN (1,2) AND y IN (-5,-6)
537 }
538 } {}
539 execsql {CREATE TABLE tx AS SELECT * FROM t1}
540 do_test where2-8.3 {
541 execsql {
542 SELECT w FROM t1
543 WHERE x IN (SELECT x FROM tx WHERE rowid<0)
544 AND +y IN (SELECT y FROM tx WHERE rowid=1)
545 }
546 } {}
547 do_test where2-8.4 {
548 execsql {
549 SELECT w FROM t1
550 WHERE x IN (SELECT x FROM tx WHERE rowid=1)
551 AND y IN (SELECT y FROM tx WHERE rowid<0)
552 }
553 } {}
554 #set sqlite_where_trace 1
555 do_test where2-8.5 {
556 execsql {
557 CREATE INDEX tx_xyz ON tx(x, y, z, w);
558 SELECT w FROM tx
559 WHERE x IN (SELECT x FROM t1 WHERE w BETWEEN 10 AND 20)
560 AND y IN (SELECT y FROM t1 WHERE w BETWEEN 10 AND 20)
561 AND z IN (SELECT z FROM t1 WHERE w BETWEEN 12 AND 14)
562 }
563 } {12 13 14}
564 do_test where2-8.6 {
565 execsql {
566 SELECT w FROM tx
567 WHERE x IN (SELECT x FROM t1 WHERE w BETWEEN 10 AND 20)
568 AND y IN (SELECT y FROM t1 WHERE w BETWEEN 12 AND 14)
569 AND z IN (SELECT z FROM t1 WHERE w BETWEEN 10 AND 20)
570 }
571 } {12 13 14}
572 do_test where2-8.7 {
573 execsql {
574 SELECT w FROM tx
575 WHERE x IN (SELECT x FROM t1 WHERE w BETWEEN 12 AND 14)
576 AND y IN (SELECT y FROM t1 WHERE w BETWEEN 10 AND 20)
577 AND z IN (SELECT z FROM t1 WHERE w BETWEEN 10 AND 20)
578 }
579 } {10 11 12 13 14 15}
580 do_test where2-8.8 {
581 execsql {
582 SELECT w FROM tx
583 WHERE x IN (SELECT x FROM t1 WHERE w BETWEEN 10 AND 20)
584 AND y IN (SELECT y FROM t1 WHERE w BETWEEN 10 AND 20)
585 AND z IN (SELECT z FROM t1 WHERE w BETWEEN 10 AND 20)
586 }
587 } {10 11 12 13 14 15 16 17 18 19 20}
588 do_test where2-8.9 {
589 execsql {
590 SELECT w FROM tx
591 WHERE x IN (SELECT x FROM t1 WHERE w BETWEEN 10 AND 20)
592 AND y IN (SELECT y FROM t1 WHERE w BETWEEN 10 AND 20)
593 AND z IN (SELECT z FROM t1 WHERE w BETWEEN 2 AND 4)
594 }
595 } {}
596 do_test where2-8.10 {
597 execsql {
598 SELECT w FROM tx
599 WHERE x IN (SELECT x FROM t1 WHERE w BETWEEN 10 AND 20)
600 AND y IN (SELECT y FROM t1 WHERE w BETWEEN 2 AND 4)
601 AND z IN (SELECT z FROM t1 WHERE w BETWEEN 10 AND 20)
602 }
603 } {}
604 do_test where2-8.11 {
605 execsql {
606 SELECT w FROM tx
607 WHERE x IN (SELECT x FROM t1 WHERE w BETWEEN 2 AND 4)
608 AND y IN (SELECT y FROM t1 WHERE w BETWEEN 10 AND 20)
609 AND z IN (SELECT z FROM t1 WHERE w BETWEEN 10 AND 20)
610 }
611 } {}
612 do_test where2-8.12 {
613 execsql {
614 SELECT w FROM tx
615 WHERE x IN (SELECT x FROM t1 WHERE w BETWEEN 10 AND 20)
616 AND y IN (SELECT y FROM t1 WHERE w BETWEEN 10 AND 20)
617 AND z IN (SELECT z FROM t1 WHERE w BETWEEN -4 AND -2)
618 }
619 } {}
620 do_test where2-8.13 {
621 execsql {
622 SELECT w FROM tx
623 WHERE x IN (SELECT x FROM t1 WHERE w BETWEEN 10 AND 20)
624 AND y IN (SELECT y FROM t1 WHERE w BETWEEN -4 AND -2)
625 AND z IN (SELECT z FROM t1 WHERE w BETWEEN 10 AND 20)
626 }
627 } {}
628 do_test where2-8.14 {
629 execsql {
630 SELECT w FROM tx
631 WHERE x IN (SELECT x FROM t1 WHERE w BETWEEN -4 AND -2)
632 AND y IN (SELECT y FROM t1 WHERE w BETWEEN 10 AND 20)
633 AND z IN (SELECT z FROM t1 WHERE w BETWEEN 10 AND 20)
634 }
635 } {}
636 do_test where2-8.15 {
637 execsql {
638 SELECT w FROM tx
639 WHERE x IN (SELECT x FROM t1 WHERE w BETWEEN 10 AND 20)
640 AND y IN (SELECT y FROM t1 WHERE w BETWEEN 10 AND 20)
641 AND z IN (SELECT z FROM t1 WHERE w BETWEEN 200 AND 300)
642 }
643 } {}
644 do_test where2-8.16 {
645 execsql {
646 SELECT w FROM tx
647 WHERE x IN (SELECT x FROM t1 WHERE w BETWEEN 10 AND 20)
648 AND y IN (SELECT y FROM t1 WHERE w BETWEEN 200 AND 300)
649 AND z IN (SELECT z FROM t1 WHERE w BETWEEN 10 AND 20)
650 }
651 } {}
652 do_test where2-8.17 {
653 execsql {
654 SELECT w FROM tx
655 WHERE x IN (SELECT x FROM t1 WHERE w BETWEEN 200 AND 300)
656 AND y IN (SELECT y FROM t1 WHERE w BETWEEN 10 AND 20)
657 AND z IN (SELECT z FROM t1 WHERE w BETWEEN 10 AND 20)
658 }
659 } {}
660 do_test where2-8.18 {
661 execsql {
662 SELECT w FROM tx
663 WHERE x IN (SELECT x FROM t1 WHERE +w BETWEEN 10 AND 20)
664 AND y IN (SELECT y FROM t1 WHERE +w BETWEEN 10 AND 20)
665 AND z IN (SELECT z FROM t1 WHERE +w BETWEEN 200 AND 300)
666 }
667 } {}
668 do_test where2-8.19 {
669 execsql {
670 SELECT w FROM tx
671 WHERE x IN (SELECT x FROM t1 WHERE +w BETWEEN 10 AND 20)
672 AND y IN (SELECT y FROM t1 WHERE +w BETWEEN 200 AND 300)
673 AND z IN (SELECT z FROM t1 WHERE +w BETWEEN 10 AND 20)
674 }
675 } {}
676 do_test where2-8.20 {
677 execsql {
678 SELECT w FROM tx
679 WHERE x IN (SELECT x FROM t1 WHERE +w BETWEEN 200 AND 300)
680 AND y IN (SELECT y FROM t1 WHERE +w BETWEEN 10 AND 20)
681 AND z IN (SELECT z FROM t1 WHERE +w BETWEEN 10 AND 20)
682 }
683 } {}
684}
drh38276582006-11-06 15:10:05 +0000685
686# Make sure WHERE clauses of the form A=1 AND (B=2 OR B=3) are optimized
687# when we have an index on A and B.
688#
danielk19774152e672007-09-12 17:01:45 +0000689ifcapable or_opt&&tclvar {
drh38276582006-11-06 15:10:05 +0000690 do_test where2-9.1 {
691 execsql {
692 BEGIN;
693 CREATE TABLE t10(a,b,c);
694 INSERT INTO t10 VALUES(1,1,1);
695 INSERT INTO t10 VALUES(1,2,2);
696 INSERT INTO t10 VALUES(1,3,3);
697 }
698 for {set i 4} {$i<=1000} {incr i} {
699 execsql {INSERT INTO t10 VALUES(1,$i,$i)}
700 }
701 execsql {
702 CREATE INDEX i10 ON t10(a,b);
703 COMMIT;
704 SELECT count(*) FROM t10;
705 }
706 } 1000
danielk1977284f4ac2007-12-10 05:03:46 +0000707 ifcapable subquery {
708 do_test where2-9.2 {
709 count {
710 SELECT * FROM t10 WHERE a=1 AND (b=2 OR b=3)
711 }
712 } {1 2 2 1 3 3 7}
713 }
drh38276582006-11-06 15:10:05 +0000714}
715
drhbe837bd2010-04-30 21:03:24 +0000716# Indices with redundant columns
717#
718do_test where2-11.1 {
719 execsql {
720 CREATE TABLE t11(a,b,c,d);
721 CREATE INDEX i11aba ON t11(a,b,a,c); -- column A occurs twice.
722 INSERT INTO t11 VALUES(1,2,3,4);
723 INSERT INTO t11 VALUES(5,6,7,8);
724 INSERT INTO t11 VALUES(1,2,9,10);
725 INSERT INTO t11 VALUES(5,11,12,13);
726 SELECT c FROM t11 WHERE a=1 AND b=2 ORDER BY c;
727 }
728} {3 9}
729do_test where2-11.2 {
730 execsql {
731 CREATE INDEX i11cccccccc ON t11(c,c,c,c,c,c,c,c); -- repeated column
732 SELECT d FROM t11 WHERE c=9;
733 }
734} {10}
735do_test where2-11.3 {
736 execsql {
737 SELECT d FROM t11 WHERE c IN (1,2,3,4,5);
738 }
739} {4}
740do_test where2-11.4 {
741 execsql {
742 SELECT d FROM t11 WHERE c=7 OR (a=1 AND b=2) ORDER BY d;
743 }
744} {4 8 10}
745
drhaa32e3c2013-07-16 21:31:23 +0000746# Verify that the OR clause is used in an outer loop even when
747# the OR clause scores slightly better on an inner loop.
danc63e8802013-08-21 20:04:54 +0000748if {[permutation] != "no_optimization"} {
drhaa32e3c2013-07-16 21:31:23 +0000749do_execsql_test where2-12.1 {
drh165674d2013-10-04 15:58:59 +0000750 CREATE TABLE t12(x INTEGER PRIMARY KEY, y INT, z CHAR(100));
drhaa32e3c2013-07-16 21:31:23 +0000751 CREATE INDEX t12y ON t12(y);
752 EXPLAIN QUERY PLAN
753 SELECT a.x, b.x
754 FROM t12 AS a JOIN t12 AS b ON a.y=b.x
755 WHERE (b.x=$abc OR b.y=$abc);
756} {/.*SEARCH TABLE t12 AS b .*SEARCH TABLE t12 AS b .*/}
danc63e8802013-08-21 20:04:54 +0000757}
drhaa32e3c2013-07-16 21:31:23 +0000758
drha45fdc72014-07-22 19:14:42 +0000759# Verify that all necessary OP_OpenRead opcodes occur in the OR optimization.
760#
761do_execsql_test where2-13.1 {
762 CREATE TABLE t13(a,b);
763 CREATE INDEX t13a ON t13(a);
764 INSERT INTO t13 VALUES(4,5);
765 SELECT * FROM t13 WHERE (1=2 AND a=3) OR a=4;
766} {4 5}
drhbe837bd2010-04-30 21:03:24 +0000767
drh90730c92016-03-09 15:09:22 +0000768# https://www.sqlite.org/src/info/5e3c886796e5512e (2016-03-09)
769# Correlated subquery on the RHS of an IN operator
770#
771do_execsql_test where2-14.1 {
772 CREATE TABLE t14a(x INTEGER PRIMARY KEY);
773 INSERT INTO t14a(x) VALUES(1),(2),(3),(4);
774 CREATE TABLE t14b(y INTEGER PRIMARY KEY);
775 INSERT INTO t14b(y) VALUES(1);
776 SELECT x FROM t14a WHERE x NOT IN (SELECT x FROM t14b);
777} {}
778
drha6110402005-07-28 20:51:19 +0000779finish_test