blob: 45ea486d959577608eba0eae22060cd39491a743 [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
124
125# Efficient handling of forward and reverse table scans.
126#
127do_test where2-3.1 {
128 queryplan {
129 SELECT * FROM t1 ORDER BY rowid LIMIT 2
130 }
131} {1 0 4 4 2 1 9 10 nosort t1 *}
132do_test where2-3.2 {
133 queryplan {
134 SELECT * FROM t1 ORDER BY rowid DESC LIMIT 2
135 }
136} {100 6 10201 10207 99 6 10000 10006 nosort t1 *}
137
138# The IN operator can be used by indices at multiple layers
139#
danielk19771576cd92006-01-14 08:02:28 +0000140ifcapable subquery {
141 do_test where2-4.1 {
142 queryplan {
143 SELECT * FROM t1 WHERE z IN (10207,10006) AND y IN (10000,10201)
144 AND x>0 AND x<10
145 ORDER BY w
146 }
147 } {99 6 10000 10006 100 6 10201 10207 sort t1 i1zyx}
148 do_test where2-4.2 {
149 queryplan {
150 SELECT * FROM t1 WHERE z IN (10207,10006) AND y=10000
151 AND x>0 AND x<10
152 ORDER BY w
153 }
154 } {99 6 10000 10006 sort t1 i1zyx}
155 do_test where2-4.3 {
156 queryplan {
157 SELECT * FROM t1 WHERE z=10006 AND y IN (10000,10201)
158 AND x>0 AND x<10
159 ORDER BY w
160 }
161 } {99 6 10000 10006 sort t1 i1zyx}
danielk1977ff890792006-01-16 16:24:25 +0000162 ifcapable compound {
163 do_test where2-4.4 {
164 queryplan {
165 SELECT * FROM t1 WHERE z IN (SELECT 10207 UNION SELECT 10006)
166 AND y IN (10000,10201)
167 AND x>0 AND x<10
168 ORDER BY w
169 }
170 } {99 6 10000 10006 100 6 10201 10207 sort t1 i1zyx}
171 do_test where2-4.5 {
172 queryplan {
173 SELECT * FROM t1 WHERE z IN (SELECT 10207 UNION SELECT 10006)
174 AND y IN (SELECT 10000 UNION SELECT 10201)
175 AND x>0 AND x<10
176 ORDER BY w
177 }
178 } {99 6 10000 10006 100 6 10201 10207 sort t1 i1zyx}
179 }
drh1b8fc652013-02-07 21:15:14 +0000180 do_test where2-4.6a {
danielk19771576cd92006-01-14 08:02:28 +0000181 queryplan {
182 SELECT * FROM t1
183 WHERE x IN (1,2,3,4,5,6,7,8)
184 AND y IN (10000,10001,10002,10003,10004,10005)
drh1b8fc652013-02-07 21:15:14 +0000185 ORDER BY x
186 }
187 } {99 6 10000 10006 nosort t1 i1xy}
188 do_test where2-4.6b {
189 queryplan {
190 SELECT * FROM t1
191 WHERE x IN (1,2,3,4,5,6,7,8)
192 AND y IN (10000,10001,10002,10003,10004,10005)
193 ORDER BY x DESC
194 }
drh2d96b932013-02-08 18:48:23 +0000195 } {99 6 10000 10006 nosort t1 i1xy}
drh1b8fc652013-02-07 21:15:14 +0000196 do_test where2-4.6c {
197 queryplan {
198 SELECT * FROM t1
199 WHERE x IN (1,2,3,4,5,6,7,8)
200 AND y IN (10000,10001,10002,10003,10004,10005)
201 ORDER BY x, y
202 }
203 } {99 6 10000 10006 nosort t1 i1xy}
204 do_test where2-4.6d {
205 queryplan {
206 SELECT * FROM t1
207 WHERE x IN (1,2,3,4,5,6,7,8)
208 AND y IN (10000,10001,10002,10003,10004,10005)
209 ORDER BY x, y DESC
danielk19771576cd92006-01-14 08:02:28 +0000210 }
211 } {99 6 10000 10006 sort t1 i1xy}
drha6110402005-07-28 20:51:19 +0000212
danielk19771576cd92006-01-14 08:02:28 +0000213 # Duplicate entires on the RHS of an IN operator do not cause duplicate
214 # output rows.
215 #
drh1b8fc652013-02-07 21:15:14 +0000216 do_test where2-4.6x {
danielk19771576cd92006-01-14 08:02:28 +0000217 queryplan {
218 SELECT * FROM t1 WHERE z IN (10207,10006,10006,10207)
219 ORDER BY w
220 }
221 } {99 6 10000 10006 100 6 10201 10207 sort t1 i1zyx}
drh1b8fc652013-02-07 21:15:14 +0000222 do_test where2-4.6y {
223 queryplan {
224 SELECT * FROM t1 WHERE z IN (10207,10006,10006,10207)
225 ORDER BY w DESC
226 }
227 } {100 6 10201 10207 99 6 10000 10006 sort t1 i1zyx}
danielk1977ff890792006-01-16 16:24:25 +0000228 ifcapable compound {
229 do_test where2-4.7 {
230 queryplan {
231 SELECT * FROM t1 WHERE z IN (
232 SELECT 10207 UNION ALL SELECT 10006
233 UNION ALL SELECT 10006 UNION ALL SELECT 10207)
234 ORDER BY w
235 }
236 } {99 6 10000 10006 100 6 10201 10207 sort t1 i1zyx}
237 }
danielk19771576cd92006-01-14 08:02:28 +0000238
239} ;# ifcapable subquery
drha6110402005-07-28 20:51:19 +0000240
241# The use of an IN operator disables the index as a sorter.
242#
243do_test where2-5.1 {
244 queryplan {
245 SELECT * FROM t1 WHERE w=99 ORDER BY w
246 }
247} {99 6 10000 10006 nosort t1 i1w}
danielk19771576cd92006-01-14 08:02:28 +0000248
249ifcapable subquery {
drh1b8fc652013-02-07 21:15:14 +0000250 do_test where2-5.2a {
danielk19771576cd92006-01-14 08:02:28 +0000251 queryplan {
252 SELECT * FROM t1 WHERE w IN (99) ORDER BY w
253 }
drh1b8fc652013-02-07 21:15:14 +0000254 } {99 6 10000 10006 nosort t1 i1w}
255 do_test where2-5.2b {
256 queryplan {
257 SELECT * FROM t1 WHERE w IN (99) ORDER BY w DESC
258 }
drh2d96b932013-02-08 18:48:23 +0000259 } {99 6 10000 10006 nosort t1 i1w}
danielk19771576cd92006-01-14 08:02:28 +0000260}
drha6110402005-07-28 20:51:19 +0000261
drh6c30be82005-07-29 15:10:17 +0000262# Verify that OR clauses get translated into IN operators.
263#
danielk19771576cd92006-01-14 08:02:28 +0000264set ::idx {}
265ifcapable subquery {set ::idx i1w}
drh3e355802007-02-23 23:13:33 +0000266do_test where2-6.1.1 {
drh6c30be82005-07-29 15:10:17 +0000267 queryplan {
268 SELECT * FROM t1 WHERE w=99 OR w=100 ORDER BY +w
269 }
danielk19771576cd92006-01-14 08:02:28 +0000270} [list 99 6 10000 10006 100 6 10201 10207 sort t1 $::idx]
drh3e355802007-02-23 23:13:33 +0000271do_test where2-6.1.2 {
272 queryplan {
273 SELECT * FROM t1 WHERE 99=w OR 100=w ORDER BY +w
274 }
275} [list 99 6 10000 10006 100 6 10201 10207 sort t1 $::idx]
drh6c30be82005-07-29 15:10:17 +0000276do_test where2-6.2 {
277 queryplan {
278 SELECT * FROM t1 WHERE w=99 OR w=100 OR 6=w ORDER BY +w
279 }
danielk19771576cd92006-01-14 08:02:28 +0000280} [list 6 2 49 51 99 6 10000 10006 100 6 10201 10207 sort t1 $::idx]
281
drh6c30be82005-07-29 15:10:17 +0000282do_test where2-6.3 {
283 queryplan {
284 SELECT * FROM t1 WHERE w=99 OR w=100 OR 6=+w ORDER BY +w
285 }
drh4fe425a2013-06-12 17:08:06 +0000286} {6 2 49 51 99 6 10000 10006 100 6 10201 10207 sort t1 *}
drh6c30be82005-07-29 15:10:17 +0000287do_test where2-6.4 {
288 queryplan {
289 SELECT * FROM t1 WHERE w=99 OR +w=100 OR 6=w ORDER BY +w
290 }
drh4fe425a2013-06-12 17:08:06 +0000291} {6 2 49 51 99 6 10000 10006 100 6 10201 10207 sort t1 *}
danielk19771576cd92006-01-14 08:02:28 +0000292
293set ::idx {}
294ifcapable subquery {set ::idx i1zyx}
drh6c30be82005-07-29 15:10:17 +0000295do_test where2-6.5 {
296 queryplan {
297 SELECT b.* FROM t1 a, t1 b
298 WHERE a.w=1 AND (a.y=b.z OR b.z=10)
299 ORDER BY +b.w
300 }
danielk19771576cd92006-01-14 08:02:28 +0000301} [list 1 0 4 4 2 1 9 10 sort a i1w b $::idx]
drh6c30be82005-07-29 15:10:17 +0000302do_test where2-6.6 {
303 queryplan {
304 SELECT b.* FROM t1 a, t1 b
305 WHERE a.w=1 AND (b.z=10 OR a.y=b.z OR b.z=10)
306 ORDER BY +b.w
307 }
danielk19771576cd92006-01-14 08:02:28 +0000308} [list 1 0 4 4 2 1 9 10 sort a i1w b $::idx]
drh6c30be82005-07-29 15:10:17 +0000309
danc1f19f92013-07-05 19:16:58 +0000310if {[permutation] != "no_optimization"} {
311
drh3e355802007-02-23 23:13:33 +0000312# Ticket #2249. Make sure the OR optimization is not attempted if
313# comparisons between columns of different affinities are needed.
314#
315do_test where2-6.7 {
316 execsql {
drh165674d2013-10-04 15:58:59 +0000317 CREATE TABLE t2249a(a TEXT UNIQUE, x CHAR(100));
drh3e355802007-02-23 23:13:33 +0000318 CREATE TABLE t2249b(b INTEGER);
drh165674d2013-10-04 15:58:59 +0000319 INSERT INTO t2249a(a) VALUES('0123');
drh3e355802007-02-23 23:13:33 +0000320 INSERT INTO t2249b VALUES(123);
321 }
322 queryplan {
323 -- Because a is type TEXT and b is type INTEGER, both a and b
324 -- will attempt to convert to NUMERIC before the comparison.
325 -- They will thus compare equal.
326 --
drh165674d2013-10-04 15:58:59 +0000327 SELECT b,a FROM t2249b CROSS JOIN t2249a WHERE a=b;
drh3e355802007-02-23 23:13:33 +0000328 }
drh4fe425a2013-06-12 17:08:06 +0000329} {123 0123 nosort t2249b * t2249a sqlite_autoindex_t2249a_1}
drh3e355802007-02-23 23:13:33 +0000330do_test where2-6.9 {
331 queryplan {
332 -- The + operator removes affinity from the rhs. No conversions
333 -- occur and the comparison is false. The result is an empty set.
334 --
drh165674d2013-10-04 15:58:59 +0000335 SELECT b,a FROM t2249b CROSS JOIN t2249a WHERE a=+b;
drh3e355802007-02-23 23:13:33 +0000336 }
drh4fe425a2013-06-12 17:08:06 +0000337} {nosort t2249b * t2249a sqlite_autoindex_t2249a_1}
drh3e355802007-02-23 23:13:33 +0000338do_test where2-6.9.2 {
339 # The same thing but with the expression flipped around.
340 queryplan {
drh165674d2013-10-04 15:58:59 +0000341 SELECT b,a FROM t2249b CROSS JOIN t2249a WHERE +b=a
drh3e355802007-02-23 23:13:33 +0000342 }
drh4fe425a2013-06-12 17:08:06 +0000343} {nosort t2249b * t2249a sqlite_autoindex_t2249a_1}
drh3e355802007-02-23 23:13:33 +0000344do_test where2-6.10 {
345 queryplan {
346 -- Use + on both sides of the comparison to disable indices
347 -- completely. Make sure we get the same result.
348 --
drh165674d2013-10-04 15:58:59 +0000349 SELECT b,a FROM t2249b CROSS JOIN t2249a WHERE +a=+b;
drh3e355802007-02-23 23:13:33 +0000350 }
drh4fe425a2013-06-12 17:08:06 +0000351} {nosort t2249b * t2249a sqlite_autoindex_t2249a_1}
drh3e355802007-02-23 23:13:33 +0000352do_test where2-6.11 {
353 # This will not attempt the OR optimization because of the a=b
354 # comparison.
355 queryplan {
drh165674d2013-10-04 15:58:59 +0000356 SELECT b,a FROM t2249b CROSS JOIN t2249a WHERE a=b OR a='hello';
drh3e355802007-02-23 23:13:33 +0000357 }
drh4fe425a2013-06-12 17:08:06 +0000358} {123 0123 nosort t2249b * t2249a sqlite_autoindex_t2249a_1}
drh3e355802007-02-23 23:13:33 +0000359do_test where2-6.11.2 {
360 # Permutations of the expression terms.
361 queryplan {
drh165674d2013-10-04 15:58:59 +0000362 SELECT b,a FROM t2249b CROSS JOIN t2249a WHERE b=a OR a='hello';
drh3e355802007-02-23 23:13:33 +0000363 }
drh4fe425a2013-06-12 17:08:06 +0000364} {123 0123 nosort t2249b * t2249a sqlite_autoindex_t2249a_1}
drh3e355802007-02-23 23:13:33 +0000365do_test where2-6.11.3 {
366 # Permutations of the expression terms.
367 queryplan {
drh165674d2013-10-04 15:58:59 +0000368 SELECT b,a FROM t2249b CROSS JOIN t2249a WHERE 'hello'=a OR b=a;
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.11.4 {
372 # Permutations of the expression terms.
373 queryplan {
drh165674d2013-10-04 15:58:59 +0000374 SELECT b,a FROM t2249b CROSS JOIN t2249a WHERE a='hello' OR b=a;
drh3e355802007-02-23 23:13:33 +0000375 }
drh4fe425a2013-06-12 17:08:06 +0000376} {123 0123 nosort t2249b * t2249a sqlite_autoindex_t2249a_1}
danielk1977284f4ac2007-12-10 05:03:46 +0000377ifcapable explain&&subquery {
378 # These tests are not run if subquery support is not included in the
379 # build. This is because these tests test the "a = 1 OR a = 2" to
380 # "a IN (1, 2)" optimisation transformation, which is not enabled if
381 # subqueries and the IN operator is not available.
382 #
danielk19774152e672007-09-12 17:01:45 +0000383 do_test where2-6.12 {
384 # In this case, the +b disables the affinity conflict and allows
385 # the OR optimization to be used again. The result is now an empty
386 # set, the same as in where2-6.9.
387 queryplan {
drh165674d2013-10-04 15:58:59 +0000388 SELECT b,a FROM t2249b CROSS JOIN t2249a WHERE a=+b OR a='hello';
danielk19774152e672007-09-12 17:01:45 +0000389 }
drh4fe425a2013-06-12 17:08:06 +0000390 } {nosort t2249b * t2249a sqlite_autoindex_t2249a_1}
danielk19774152e672007-09-12 17:01:45 +0000391 do_test where2-6.12.2 {
392 # In this case, the +b disables the affinity conflict and allows
393 # the OR optimization to be used again. The result is now an empty
394 # set, the same as in where2-6.9.
395 queryplan {
drh165674d2013-10-04 15:58:59 +0000396 SELECT b,a FROM t2249b CROSS JOIN t2249a WHERE a='hello' OR +b=a;
danielk19774152e672007-09-12 17:01:45 +0000397 }
drh4fe425a2013-06-12 17:08:06 +0000398 } {nosort t2249b * t2249a sqlite_autoindex_t2249a_1}
danielk19774152e672007-09-12 17:01:45 +0000399 do_test where2-6.12.3 {
400 # In this case, the +b disables the affinity conflict and allows
401 # the OR optimization to be used again. The result is now an empty
402 # set, the same as in where2-6.9.
403 queryplan {
drh165674d2013-10-04 15:58:59 +0000404 SELECT b,a FROM t2249b CROSS JOIN t2249a WHERE +b=a OR a='hello';
danielk19774152e672007-09-12 17:01:45 +0000405 }
drh4fe425a2013-06-12 17:08:06 +0000406 } {nosort t2249b * t2249a sqlite_autoindex_t2249a_1}
danielk19774152e672007-09-12 17:01:45 +0000407 do_test where2-6.13 {
408 # The addition of +a on the second term disabled the OR optimization.
409 # But we should still get the same empty-set result as in where2-6.9.
410 queryplan {
drh165674d2013-10-04 15:58:59 +0000411 SELECT b,a FROM t2249b CROSS JOIN t2249a WHERE a=+b OR +a='hello';
danielk19774152e672007-09-12 17:01:45 +0000412 }
drh4fe425a2013-06-12 17:08:06 +0000413 } {nosort t2249b * t2249a sqlite_autoindex_t2249a_1}
danielk19774152e672007-09-12 17:01:45 +0000414}
drh3e355802007-02-23 23:13:33 +0000415
416# Variations on the order of terms in a WHERE clause in order
417# to make sure the OR optimizer can recognize them all.
418do_test where2-6.20 {
419 queryplan {
drh165674d2013-10-04 15:58:59 +0000420 SELECT x.a, y.a FROM t2249a x CROSS JOIN t2249a y WHERE x.a=y.a
drh3e355802007-02-23 23:13:33 +0000421 }
drh4fe425a2013-06-12 17:08:06 +0000422} {0123 0123 nosort x sqlite_autoindex_t2249a_1 y sqlite_autoindex_t2249a_1}
danielk1977284f4ac2007-12-10 05:03:46 +0000423ifcapable explain&&subquery {
424 # These tests are not run if subquery support is not included in the
425 # build. This is because these tests test the "a = 1 OR a = 2" to
426 # "a IN (1, 2)" optimisation transformation, which is not enabled if
427 # subqueries and the IN operator is not available.
428 #
danielk19774152e672007-09-12 17:01:45 +0000429 do_test where2-6.21 {
430 queryplan {
drh165674d2013-10-04 15:58:59 +0000431 SELECT x.a,y.a FROM t2249a x CROSS JOIN t2249a y
432 WHERE x.a=y.a OR y.a='hello'
danielk19774152e672007-09-12 17:01:45 +0000433 }
drh4fe425a2013-06-12 17:08:06 +0000434 } {0123 0123 nosort x sqlite_autoindex_t2249a_1 y sqlite_autoindex_t2249a_1}
danielk19774152e672007-09-12 17:01:45 +0000435 do_test where2-6.22 {
436 queryplan {
drh165674d2013-10-04 15:58:59 +0000437 SELECT x.a,y.a FROM t2249a x CROSS JOIN t2249a y
438 WHERE y.a=x.a OR y.a='hello'
danielk19774152e672007-09-12 17:01:45 +0000439 }
drh4fe425a2013-06-12 17:08:06 +0000440 } {0123 0123 nosort x sqlite_autoindex_t2249a_1 y sqlite_autoindex_t2249a_1}
danielk19774152e672007-09-12 17:01:45 +0000441 do_test where2-6.23 {
442 queryplan {
drh165674d2013-10-04 15:58:59 +0000443 SELECT x.a,y.a FROM t2249a x CROSS JOIN t2249a y
444 WHERE y.a='hello' OR x.a=y.a
danielk19774152e672007-09-12 17:01:45 +0000445 }
drh4fe425a2013-06-12 17:08:06 +0000446 } {0123 0123 nosort x sqlite_autoindex_t2249a_1 y sqlite_autoindex_t2249a_1}
danielk19774152e672007-09-12 17:01:45 +0000447}
drh3e355802007-02-23 23:13:33 +0000448
drh8718f522005-08-13 16:13:04 +0000449# Unique queries (queries that are guaranteed to return only a single
450# row of result) do not call the sorter. But all tables must give
451# a unique result. If any one table in the join does not give a unique
452# result then sorting is necessary.
453#
454do_test where2-7.1 {
455 cksort {
456 create table t8(a unique, b, c);
457 insert into t8 values(1,2,3);
458 insert into t8 values(2,3,4);
459 create table t9(x,y);
460 insert into t9 values(2,4);
461 insert into t9 values(2,3);
462 select y from t8, t9 where a=1 order by a, y;
463 }
464} {3 4 sort}
465do_test where2-7.2 {
466 cksort {
467 select * from t8 where a=1 order by b, c
468 }
469} {1 2 3 nosort}
470do_test where2-7.3 {
471 cksort {
472 select * from t8, t9 where a=1 and y=3 order by b, x
473 }
474} {1 2 3 2 3 sort}
475do_test where2-7.4 {
476 cksort {
477 create unique index i9y on t9(y);
478 select * from t8, t9 where a=1 and y=3 order by b, x
479 }
480} {1 2 3 2 3 nosort}
drha6110402005-07-28 20:51:19 +0000481
danc1f19f92013-07-05 19:16:58 +0000482} ;# if {[permutation] != "no_optimization"}
483
drhffe0f892006-05-11 13:26:25 +0000484# Ticket #1807. Using IN constrains on multiple columns of
485# a multi-column index.
486#
487ifcapable subquery {
488 do_test where2-8.1 {
489 execsql {
490 SELECT * FROM t1 WHERE x IN (20,21) AND y IN (1,2)
491 }
492 } {}
493 do_test where2-8.2 {
494 execsql {
495 SELECT * FROM t1 WHERE x IN (1,2) AND y IN (-5,-6)
496 }
497 } {}
498 execsql {CREATE TABLE tx AS SELECT * FROM t1}
499 do_test where2-8.3 {
500 execsql {
501 SELECT w FROM t1
502 WHERE x IN (SELECT x FROM tx WHERE rowid<0)
503 AND +y IN (SELECT y FROM tx WHERE rowid=1)
504 }
505 } {}
506 do_test where2-8.4 {
507 execsql {
508 SELECT w FROM t1
509 WHERE x IN (SELECT x FROM tx WHERE rowid=1)
510 AND y IN (SELECT y FROM tx WHERE rowid<0)
511 }
512 } {}
513 #set sqlite_where_trace 1
514 do_test where2-8.5 {
515 execsql {
516 CREATE INDEX tx_xyz ON tx(x, y, z, w);
517 SELECT w FROM tx
518 WHERE x IN (SELECT x FROM t1 WHERE w BETWEEN 10 AND 20)
519 AND y IN (SELECT y FROM t1 WHERE w BETWEEN 10 AND 20)
520 AND z IN (SELECT z FROM t1 WHERE w BETWEEN 12 AND 14)
521 }
522 } {12 13 14}
523 do_test where2-8.6 {
524 execsql {
525 SELECT w FROM tx
526 WHERE x IN (SELECT x FROM t1 WHERE w BETWEEN 10 AND 20)
527 AND y IN (SELECT y FROM t1 WHERE w BETWEEN 12 AND 14)
528 AND z IN (SELECT z FROM t1 WHERE w BETWEEN 10 AND 20)
529 }
530 } {12 13 14}
531 do_test where2-8.7 {
532 execsql {
533 SELECT w FROM tx
534 WHERE x IN (SELECT x FROM t1 WHERE w BETWEEN 12 AND 14)
535 AND y IN (SELECT y FROM t1 WHERE w BETWEEN 10 AND 20)
536 AND z IN (SELECT z FROM t1 WHERE w BETWEEN 10 AND 20)
537 }
538 } {10 11 12 13 14 15}
539 do_test where2-8.8 {
540 execsql {
541 SELECT w FROM tx
542 WHERE x IN (SELECT x FROM t1 WHERE w BETWEEN 10 AND 20)
543 AND y IN (SELECT y FROM t1 WHERE w BETWEEN 10 AND 20)
544 AND z IN (SELECT z FROM t1 WHERE w BETWEEN 10 AND 20)
545 }
546 } {10 11 12 13 14 15 16 17 18 19 20}
547 do_test where2-8.9 {
548 execsql {
549 SELECT w FROM tx
550 WHERE x IN (SELECT x FROM t1 WHERE w BETWEEN 10 AND 20)
551 AND y IN (SELECT y FROM t1 WHERE w BETWEEN 10 AND 20)
552 AND z IN (SELECT z FROM t1 WHERE w BETWEEN 2 AND 4)
553 }
554 } {}
555 do_test where2-8.10 {
556 execsql {
557 SELECT w FROM tx
558 WHERE x IN (SELECT x FROM t1 WHERE w BETWEEN 10 AND 20)
559 AND y IN (SELECT y FROM t1 WHERE w BETWEEN 2 AND 4)
560 AND z IN (SELECT z FROM t1 WHERE w BETWEEN 10 AND 20)
561 }
562 } {}
563 do_test where2-8.11 {
564 execsql {
565 SELECT w FROM tx
566 WHERE x IN (SELECT x FROM t1 WHERE w BETWEEN 2 AND 4)
567 AND y IN (SELECT y FROM t1 WHERE w BETWEEN 10 AND 20)
568 AND z IN (SELECT z FROM t1 WHERE w BETWEEN 10 AND 20)
569 }
570 } {}
571 do_test where2-8.12 {
572 execsql {
573 SELECT w FROM tx
574 WHERE x IN (SELECT x FROM t1 WHERE w BETWEEN 10 AND 20)
575 AND y IN (SELECT y FROM t1 WHERE w BETWEEN 10 AND 20)
576 AND z IN (SELECT z FROM t1 WHERE w BETWEEN -4 AND -2)
577 }
578 } {}
579 do_test where2-8.13 {
580 execsql {
581 SELECT w FROM tx
582 WHERE x IN (SELECT x FROM t1 WHERE w BETWEEN 10 AND 20)
583 AND y IN (SELECT y FROM t1 WHERE w BETWEEN -4 AND -2)
584 AND z IN (SELECT z FROM t1 WHERE w BETWEEN 10 AND 20)
585 }
586 } {}
587 do_test where2-8.14 {
588 execsql {
589 SELECT w FROM tx
590 WHERE x IN (SELECT x FROM t1 WHERE w BETWEEN -4 AND -2)
591 AND y IN (SELECT y FROM t1 WHERE w BETWEEN 10 AND 20)
592 AND z IN (SELECT z FROM t1 WHERE w BETWEEN 10 AND 20)
593 }
594 } {}
595 do_test where2-8.15 {
596 execsql {
597 SELECT w FROM tx
598 WHERE x IN (SELECT x FROM t1 WHERE w BETWEEN 10 AND 20)
599 AND y IN (SELECT y FROM t1 WHERE w BETWEEN 10 AND 20)
600 AND z IN (SELECT z FROM t1 WHERE w BETWEEN 200 AND 300)
601 }
602 } {}
603 do_test where2-8.16 {
604 execsql {
605 SELECT w FROM tx
606 WHERE x IN (SELECT x FROM t1 WHERE w BETWEEN 10 AND 20)
607 AND y IN (SELECT y FROM t1 WHERE w BETWEEN 200 AND 300)
608 AND z IN (SELECT z FROM t1 WHERE w BETWEEN 10 AND 20)
609 }
610 } {}
611 do_test where2-8.17 {
612 execsql {
613 SELECT w FROM tx
614 WHERE x IN (SELECT x FROM t1 WHERE w BETWEEN 200 AND 300)
615 AND y IN (SELECT y FROM t1 WHERE w BETWEEN 10 AND 20)
616 AND z IN (SELECT z FROM t1 WHERE w BETWEEN 10 AND 20)
617 }
618 } {}
619 do_test where2-8.18 {
620 execsql {
621 SELECT w FROM tx
622 WHERE x IN (SELECT x FROM t1 WHERE +w BETWEEN 10 AND 20)
623 AND y IN (SELECT y FROM t1 WHERE +w BETWEEN 10 AND 20)
624 AND z IN (SELECT z FROM t1 WHERE +w BETWEEN 200 AND 300)
625 }
626 } {}
627 do_test where2-8.19 {
628 execsql {
629 SELECT w FROM tx
630 WHERE x IN (SELECT x FROM t1 WHERE +w BETWEEN 10 AND 20)
631 AND y IN (SELECT y FROM t1 WHERE +w BETWEEN 200 AND 300)
632 AND z IN (SELECT z FROM t1 WHERE +w BETWEEN 10 AND 20)
633 }
634 } {}
635 do_test where2-8.20 {
636 execsql {
637 SELECT w FROM tx
638 WHERE x IN (SELECT x FROM t1 WHERE +w BETWEEN 200 AND 300)
639 AND y IN (SELECT y FROM t1 WHERE +w BETWEEN 10 AND 20)
640 AND z IN (SELECT z FROM t1 WHERE +w BETWEEN 10 AND 20)
641 }
642 } {}
643}
drh38276582006-11-06 15:10:05 +0000644
645# Make sure WHERE clauses of the form A=1 AND (B=2 OR B=3) are optimized
646# when we have an index on A and B.
647#
danielk19774152e672007-09-12 17:01:45 +0000648ifcapable or_opt&&tclvar {
drh38276582006-11-06 15:10:05 +0000649 do_test where2-9.1 {
650 execsql {
651 BEGIN;
652 CREATE TABLE t10(a,b,c);
653 INSERT INTO t10 VALUES(1,1,1);
654 INSERT INTO t10 VALUES(1,2,2);
655 INSERT INTO t10 VALUES(1,3,3);
656 }
657 for {set i 4} {$i<=1000} {incr i} {
658 execsql {INSERT INTO t10 VALUES(1,$i,$i)}
659 }
660 execsql {
661 CREATE INDEX i10 ON t10(a,b);
662 COMMIT;
663 SELECT count(*) FROM t10;
664 }
665 } 1000
danielk1977284f4ac2007-12-10 05:03:46 +0000666 ifcapable subquery {
667 do_test where2-9.2 {
668 count {
669 SELECT * FROM t10 WHERE a=1 AND (b=2 OR b=3)
670 }
671 } {1 2 2 1 3 3 7}
672 }
drh38276582006-11-06 15:10:05 +0000673}
674
drhbe837bd2010-04-30 21:03:24 +0000675# Indices with redundant columns
676#
677do_test where2-11.1 {
678 execsql {
679 CREATE TABLE t11(a,b,c,d);
680 CREATE INDEX i11aba ON t11(a,b,a,c); -- column A occurs twice.
681 INSERT INTO t11 VALUES(1,2,3,4);
682 INSERT INTO t11 VALUES(5,6,7,8);
683 INSERT INTO t11 VALUES(1,2,9,10);
684 INSERT INTO t11 VALUES(5,11,12,13);
685 SELECT c FROM t11 WHERE a=1 AND b=2 ORDER BY c;
686 }
687} {3 9}
688do_test where2-11.2 {
689 execsql {
690 CREATE INDEX i11cccccccc ON t11(c,c,c,c,c,c,c,c); -- repeated column
691 SELECT d FROM t11 WHERE c=9;
692 }
693} {10}
694do_test where2-11.3 {
695 execsql {
696 SELECT d FROM t11 WHERE c IN (1,2,3,4,5);
697 }
698} {4}
699do_test where2-11.4 {
700 execsql {
701 SELECT d FROM t11 WHERE c=7 OR (a=1 AND b=2) ORDER BY d;
702 }
703} {4 8 10}
704
drhaa32e3c2013-07-16 21:31:23 +0000705# Verify that the OR clause is used in an outer loop even when
706# the OR clause scores slightly better on an inner loop.
danc63e8802013-08-21 20:04:54 +0000707if {[permutation] != "no_optimization"} {
drhaa32e3c2013-07-16 21:31:23 +0000708do_execsql_test where2-12.1 {
drh165674d2013-10-04 15:58:59 +0000709 CREATE TABLE t12(x INTEGER PRIMARY KEY, y INT, z CHAR(100));
drhaa32e3c2013-07-16 21:31:23 +0000710 CREATE INDEX t12y ON t12(y);
711 EXPLAIN QUERY PLAN
712 SELECT a.x, b.x
713 FROM t12 AS a JOIN t12 AS b ON a.y=b.x
714 WHERE (b.x=$abc OR b.y=$abc);
715} {/.*SEARCH TABLE t12 AS b .*SEARCH TABLE t12 AS b .*/}
danc63e8802013-08-21 20:04:54 +0000716}
drhaa32e3c2013-07-16 21:31:23 +0000717
drhbe837bd2010-04-30 21:03:24 +0000718
drha6110402005-07-28 20:51:19 +0000719finish_test