xref: /sqlite-3.40.0/test/where9.test (revision b80bb6ce)
1# 2008 December 30
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 multi-index OR clause optimizer.
13#
14
15set testdir [file dirname $argv0]
16source $testdir/tester.tcl
17
18ifcapable !or_opt||!compound {
19  finish_test
20  return
21}
22
23# Evaluate SQL.  Return the result set followed by the
24# and the number of full-scan steps.
25#
26proc count_steps {sql} {
27  set r [db eval $sql]
28  lappend r scan [db status step] sort [db status sort]
29}
30
31
32# Construct test data.
33#
34do_test where9-1.1 {
35  db eval {
36    CREATE TABLE t1(a INTEGER PRIMARY KEY,b,c,d,e,f,g);
37    INSERT INTO t1 VALUES(1,11,1001,1.001,100.1,'bcdefghij','yxwvuts');
38    INSERT INTO t1 VALUES(2,22,1001,2.002,100.1,'cdefghijk','yxwvuts');
39    INSERT INTO t1 VALUES(3,33,1001,3.003,100.1,'defghijkl','xwvutsr');
40    INSERT INTO t1 VALUES(4,44,2002,4.004,200.2,'efghijklm','xwvutsr');
41    INSERT INTO t1 VALUES(5,55,2002,5.005,200.2,'fghijklmn','xwvutsr');
42    INSERT INTO t1 VALUES(6,66,2002,6.006,200.2,'ghijklmno','xwvutsr');
43    INSERT INTO t1 VALUES(7,77,3003,7.007,300.3,'hijklmnop','xwvutsr');
44    INSERT INTO t1 VALUES(8,88,3003,8.008,300.3,'ijklmnopq','wvutsrq');
45    INSERT INTO t1 VALUES(9,99,3003,9.009,300.3,'jklmnopqr','wvutsrq');
46    INSERT INTO t1 VALUES(10,110,4004,10.01,400.4,'klmnopqrs','wvutsrq');
47    INSERT INTO t1 VALUES(11,121,4004,11.011,400.4,'lmnopqrst','wvutsrq');
48    INSERT INTO t1 VALUES(12,132,4004,12.012,400.4,'mnopqrstu','wvutsrq');
49    INSERT INTO t1 VALUES(13,143,5005,13.013,500.5,'nopqrstuv','vutsrqp');
50    INSERT INTO t1 VALUES(14,154,5005,14.014,500.5,'opqrstuvw','vutsrqp');
51    INSERT INTO t1 VALUES(15,165,5005,15.015,500.5,'pqrstuvwx','vutsrqp');
52    INSERT INTO t1 VALUES(16,176,6006,16.016,600.6,'qrstuvwxy','vutsrqp');
53    INSERT INTO t1 VALUES(17,187,6006,17.017,600.6,'rstuvwxyz','vutsrqp');
54    INSERT INTO t1 VALUES(18,198,6006,18.018,600.6,'stuvwxyza','utsrqpo');
55    INSERT INTO t1 VALUES(19,209,7007,19.019,700.7,'tuvwxyzab','utsrqpo');
56    INSERT INTO t1 VALUES(20,220,7007,20.02,700.7,'uvwxyzabc','utsrqpo');
57    INSERT INTO t1 VALUES(21,231,7007,21.021,700.7,'vwxyzabcd','utsrqpo');
58    INSERT INTO t1 VALUES(22,242,8008,22.022,800.8,'wxyzabcde','utsrqpo');
59    INSERT INTO t1 VALUES(23,253,8008,23.023,800.8,'xyzabcdef','tsrqpon');
60    INSERT INTO t1 VALUES(24,264,8008,24.024,800.8,'yzabcdefg','tsrqpon');
61    INSERT INTO t1 VALUES(25,275,9009,25.025,900.9,'zabcdefgh','tsrqpon');
62    INSERT INTO t1 VALUES(26,286,9009,26.026,900.9,'abcdefghi','tsrqpon');
63    INSERT INTO t1 VALUES(27,297,9009,27.027,900.9,'bcdefghij','tsrqpon');
64    INSERT INTO t1 VALUES(28,308,10010,28.028,1001.0,'cdefghijk','srqponm');
65    INSERT INTO t1 VALUES(29,319,10010,29.029,1001.0,'defghijkl','srqponm');
66    INSERT INTO t1 VALUES(30,330,10010,30.03,1001.0,'efghijklm','srqponm');
67    INSERT INTO t1 VALUES(31,341,11011,31.031,1101.1,'fghijklmn','srqponm');
68    INSERT INTO t1 VALUES(32,352,11011,32.032,1101.1,'ghijklmno','srqponm');
69    INSERT INTO t1 VALUES(33,363,11011,33.033,1101.1,'hijklmnop','rqponml');
70    INSERT INTO t1 VALUES(34,374,12012,34.034,1201.2,'ijklmnopq','rqponml');
71    INSERT INTO t1 VALUES(35,385,12012,35.035,1201.2,'jklmnopqr','rqponml');
72    INSERT INTO t1 VALUES(36,396,12012,36.036,1201.2,'klmnopqrs','rqponml');
73    INSERT INTO t1 VALUES(37,407,13013,37.037,1301.3,'lmnopqrst','rqponml');
74    INSERT INTO t1 VALUES(38,418,13013,38.038,1301.3,'mnopqrstu','qponmlk');
75    INSERT INTO t1 VALUES(39,429,13013,39.039,1301.3,'nopqrstuv','qponmlk');
76    INSERT INTO t1 VALUES(40,440,14014,40.04,1401.4,'opqrstuvw','qponmlk');
77    INSERT INTO t1 VALUES(41,451,14014,41.041,1401.4,'pqrstuvwx','qponmlk');
78    INSERT INTO t1 VALUES(42,462,14014,42.042,1401.4,'qrstuvwxy','qponmlk');
79    INSERT INTO t1 VALUES(43,473,15015,43.043,1501.5,'rstuvwxyz','ponmlkj');
80    INSERT INTO t1 VALUES(44,484,15015,44.044,1501.5,'stuvwxyza','ponmlkj');
81    INSERT INTO t1 VALUES(45,495,15015,45.045,1501.5,'tuvwxyzab','ponmlkj');
82    INSERT INTO t1 VALUES(46,506,16016,46.046,1601.6,'uvwxyzabc','ponmlkj');
83    INSERT INTO t1 VALUES(47,517,16016,47.047,1601.6,'vwxyzabcd','ponmlkj');
84    INSERT INTO t1 VALUES(48,528,16016,48.048,1601.6,'wxyzabcde','onmlkji');
85    INSERT INTO t1 VALUES(49,539,17017,49.049,1701.7,'xyzabcdef','onmlkji');
86    INSERT INTO t1 VALUES(50,550,17017,50.05,1701.7,'yzabcdefg','onmlkji');
87    INSERT INTO t1 VALUES(51,561,17017,51.051,1701.7,'zabcdefgh','onmlkji');
88    INSERT INTO t1 VALUES(52,572,18018,52.052,1801.8,'abcdefghi','onmlkji');
89    INSERT INTO t1 VALUES(53,583,18018,53.053,1801.8,'bcdefghij','nmlkjih');
90    INSERT INTO t1 VALUES(54,594,18018,54.054,1801.8,'cdefghijk','nmlkjih');
91    INSERT INTO t1 VALUES(55,605,19019,55.055,1901.9,'defghijkl','nmlkjih');
92    INSERT INTO t1 VALUES(56,616,19019,56.056,1901.9,'efghijklm','nmlkjih');
93    INSERT INTO t1 VALUES(57,627,19019,57.057,1901.9,'fghijklmn','nmlkjih');
94    INSERT INTO t1 VALUES(58,638,20020,58.058,2002.0,'ghijklmno','mlkjihg');
95    INSERT INTO t1 VALUES(59,649,20020,59.059,2002.0,'hijklmnop','mlkjihg');
96    INSERT INTO t1 VALUES(60,660,20020,60.06,2002.0,'ijklmnopq','mlkjihg');
97    INSERT INTO t1 VALUES(61,671,21021,61.061,2102.1,'jklmnopqr','mlkjihg');
98    INSERT INTO t1 VALUES(62,682,21021,62.062,2102.1,'klmnopqrs','mlkjihg');
99    INSERT INTO t1 VALUES(63,693,21021,63.063,2102.1,'lmnopqrst','lkjihgf');
100    INSERT INTO t1 VALUES(64,704,22022,64.064,2202.2,'mnopqrstu','lkjihgf');
101    INSERT INTO t1 VALUES(65,715,22022,65.065,2202.2,'nopqrstuv','lkjihgf');
102    INSERT INTO t1 VALUES(66,726,22022,66.066,2202.2,'opqrstuvw','lkjihgf');
103    INSERT INTO t1 VALUES(67,737,23023,67.067,2302.3,'pqrstuvwx','lkjihgf');
104    INSERT INTO t1 VALUES(68,748,23023,68.068,2302.3,'qrstuvwxy','kjihgfe');
105    INSERT INTO t1 VALUES(69,759,23023,69.069,2302.3,'rstuvwxyz','kjihgfe');
106    INSERT INTO t1 VALUES(70,770,24024,70.07,2402.4,'stuvwxyza','kjihgfe');
107    INSERT INTO t1 VALUES(71,781,24024,71.071,2402.4,'tuvwxyzab','kjihgfe');
108    INSERT INTO t1 VALUES(72,792,24024,72.072,2402.4,'uvwxyzabc','kjihgfe');
109    INSERT INTO t1 VALUES(73,803,25025,73.073,2502.5,'vwxyzabcd','jihgfed');
110    INSERT INTO t1 VALUES(74,814,25025,74.074,2502.5,'wxyzabcde','jihgfed');
111    INSERT INTO t1 VALUES(75,825,25025,75.075,2502.5,'xyzabcdef','jihgfed');
112    INSERT INTO t1 VALUES(76,836,26026,76.076,2602.6,'yzabcdefg','jihgfed');
113    INSERT INTO t1 VALUES(77,847,26026,77.077,2602.6,'zabcdefgh','jihgfed');
114    INSERT INTO t1 VALUES(78,858,26026,78.078,2602.6,'abcdefghi','ihgfedc');
115    INSERT INTO t1 VALUES(79,869,27027,79.079,2702.7,'bcdefghij','ihgfedc');
116    INSERT INTO t1 VALUES(80,880,27027,80.08,2702.7,'cdefghijk','ihgfedc');
117    INSERT INTO t1 VALUES(81,891,27027,81.081,2702.7,'defghijkl','ihgfedc');
118    INSERT INTO t1 VALUES(82,902,28028,82.082,2802.8,'efghijklm','ihgfedc');
119    INSERT INTO t1 VALUES(83,913,28028,83.083,2802.8,'fghijklmn','hgfedcb');
120    INSERT INTO t1 VALUES(84,924,28028,84.084,2802.8,'ghijklmno','hgfedcb');
121    INSERT INTO t1 VALUES(85,935,29029,85.085,2902.9,'hijklmnop','hgfedcb');
122    INSERT INTO t1 VALUES(86,946,29029,86.086,2902.9,'ijklmnopq','hgfedcb');
123    INSERT INTO t1 VALUES(87,957,29029,87.087,2902.9,'jklmnopqr','hgfedcb');
124    INSERT INTO t1 VALUES(88,968,30030,88.088,3003.0,'klmnopqrs','gfedcba');
125    INSERT INTO t1 VALUES(89,979,30030,89.089,3003.0,'lmnopqrst','gfedcba');
126    INSERT INTO t1 VALUES(90,NULL,30030,90.09,3003.0,'mnopqrstu','gfedcba');
127    INSERT INTO t1 VALUES(91,1001,NULL,91.091,3103.1,'nopqrstuv','gfedcba');
128    INSERT INTO t1 VALUES(92,1012,31031,NULL,3103.1,'opqrstuvw','gfedcba');
129    INSERT INTO t1 VALUES(93,1023,31031,93.093,NULL,'pqrstuvwx','fedcbaz');
130    INSERT INTO t1 VALUES(94,1034,32032,94.094,3203.2,NULL,'fedcbaz');
131    INSERT INTO t1 VALUES(95,1045,32032,95.095,3203.2,'rstuvwxyz',NULL);
132    INSERT INTO t1 VALUES(96,NULL,NULL,96.096,3203.2,'stuvwxyza','fedcbaz');
133    INSERT INTO t1 VALUES(97,1067,33033,NULL,NULL,'tuvwxyzab','fedcbaz');
134    INSERT INTO t1 VALUES(98,1078,33033,98.098,3303.3,NULL,NULL);
135    INSERT INTO t1 VALUES(99,NULL,NULL,NULL,NULL,NULL,NULL);
136    CREATE INDEX t1b ON t1(b);
137    CREATE INDEX t1c ON t1(c);
138    CREATE INDEX t1d ON t1(d);
139    CREATE INDEX t1e ON t1(e);
140    CREATE INDEX t1f ON t1(f);
141    CREATE INDEX t1g ON t1(g);
142    CREATE TABLE t2(a INTEGER PRIMARY KEY,b,c,d,e,f,g);
143    INSERT INTO t2 SELECT * FROM t1;
144    CREATE INDEX t2b ON t2(b,c);
145    CREATE INDEX t2c ON t2(c,e);
146    CREATE INDEX t2d ON t2(d,g);
147    CREATE INDEX t2e ON t2(e,f,g);
148    CREATE INDEX t2f ON t2(f,b,d,c);
149    CREATE INDEX t2g ON t2(g,f);
150    CREATE TABLE t3(x,y);
151    INSERT INTO t3 VALUES(1,80);
152    INSERT INTO t3 VALUES(2,80);
153    CREATE TABLE t4(a INTEGER PRIMARY KEY,b,c,d,e,f,g);
154    INSERT INTO t4 SELECT * FROM t1;
155    CREATE INDEX t4b ON t4(b);
156    CREATE INDEX t4c ON t4(c);
157  }
158} {}
159
160do_test where9-1.2.1 {
161  count_steps {
162    SELECT a FROM t1
163     WHERE b IS NULL
164        OR c IS NULL
165        OR d IS NULL
166    ORDER BY a
167  }
168} {90 91 92 96 97 99 scan 0 sort 1}
169do_test where9-1.2.2 {
170  count_steps {
171    SELECT a FROM t1
172     WHERE +b IS NULL
173        OR c IS NULL
174        OR d IS NULL
175    ORDER BY a
176  }
177} {90 91 92 96 97 99 scan 98 sort 0}
178do_test where9-1.2.3 {
179  count_steps {
180    SELECT a FROM t1
181     WHERE b IS NULL
182        OR +c IS NULL
183        OR d IS NULL
184    ORDER BY a
185  }
186} {90 91 92 96 97 99 scan 98 sort 0}
187do_test where9-1.2.4 {
188  count_steps {
189    SELECT a FROM t1
190     WHERE b IS NULL
191        OR c IS NULL
192        OR +d IS NULL
193    ORDER BY a
194  }
195} {90 91 92 96 97 99 scan 98 sort 0}
196do_test where9-1.2.5 {
197  count_steps {
198    SELECT a FROM t4
199     WHERE b IS NULL
200        OR c IS NULL
201        OR d IS NULL
202    ORDER BY a
203  }
204} {90 91 92 96 97 99 scan 98 sort 0}
205
206do_test where9-1.3.1 {
207  count_steps {
208    SELECT a FROM t1
209     WHERE (b IS NULL AND c NOT NULL AND d NOT NULL)
210        OR (b NOT NULL AND c IS NULL AND d NOT NULL)
211        OR (b NOT NULL AND c NOT NULL AND d IS NULL)
212    ORDER BY a
213  }
214} {90 91 92 97 scan 0 sort 1}
215do_test where9-1.3.2 {
216  count_steps {
217    SELECT a FROM t4
218     WHERE (b IS NULL AND c NOT NULL AND d NOT NULL)
219        OR (b NOT NULL AND c IS NULL AND d NOT NULL)
220        OR (b NOT NULL AND c NOT NULL AND d IS NULL)
221    ORDER BY a
222  }
223} {90 91 92 97 scan 98 sort 0}
224do_test where9-1.3.3 {
225  count_steps {
226    SELECT a FROM t4
227     WHERE (b NOT NULL AND c NOT NULL AND d IS NULL)
228        OR (b IS NULL AND c NOT NULL AND d NOT NULL)
229        OR (b NOT NULL AND c IS NULL AND d NOT NULL)
230    ORDER BY a
231  }
232} {90 91 92 97 scan 98 sort 0}
233do_test where9-1.3.4 {
234  count_steps {
235    SELECT a FROM (t4)
236     WHERE (b IS NULL AND c NOT NULL AND d NOT NULL)
237        OR (b NOT NULL AND c NOT NULL AND d IS NULL)
238        OR (b NOT NULL AND c IS NULL AND d NOT NULL)
239    ORDER BY a
240  }
241} {90 91 92 97 scan 98 sort 0}
242
243do_test where9-1.4 {
244  count_steps {
245    SELECT a FROM t1
246     WHERE (b>=950 AND b<=1010) OR (b IS NULL AND c NOT NULL)
247    ORDER BY a
248  }
249} {87 88 89 90 91 scan 0 sort 1}
250do_test where9-1.5 {
251  # When this test was originally written, SQLite used a rowset object
252  # to optimize the "ORDER BY a" clause. Now that it is using a rowhash,
253  # this is not possible. So we have to comment out one term of the OR
254  # expression in order to prevent SQLite from deeming a full-table
255  # scan to be a better strategy than using multiple indexes, which would
256  # defeat the point of the test.
257  count_steps {
258    SELECT a FROM t1
259     WHERE a=83
260        OR b=913
261        OR c=28028
262        OR (d>=82 AND d<83)
263/*      OR (e>2802 AND e<2803)  */
264        OR f='fghijklmn'
265        OR g='hgfedcb'
266    ORDER BY a
267  }
268} {5 31 57 82 83 84 85 86 87 scan 0 sort 1}
269do_test where9-1.6 {
270  count_steps {
271    SELECT a FROM t1
272     WHERE b=1012
273        OR (d IS NULL AND e IS NOT NULL)
274  }
275} {92 scan 0 sort 0}
276do_test where9-1.7 {
277  count_steps {
278    SELECT a FROM t1
279     WHERE (b=1012 OR (d IS NULL AND e IS NOT NULL))
280       AND f!=g
281  }
282} {92 scan 0 sort 0}
283do_test where9-1.8 {
284  count_steps {
285    SELECT a FROM t1
286     WHERE (b=1012 OR (d IS NULL AND e IS NOT NULL))
287       AND f==g
288  }
289} {scan 0 sort 0}
290
291do_test where9-2.1 {
292  count_steps {
293    SELECT t2.a FROM t1, t2
294     WHERE t1.a=80
295       AND (t1.c=t2.c OR t1.d=t2.d)
296    ORDER BY 1
297  }
298} {79 80 81 scan 0 sort 1}
299do_test where9-2.2 {
300  count_steps {
301    SELECT t2.a FROM t1, t2
302     WHERE t1.a=80
303       AND ((t1.c=t2.c AND t1.d=t2.d) OR t1.f=t2.f)
304    ORDER BY 1
305  }
306} {2 28 54 80 scan 0 sort 1}
307do_test where9-2.3 {
308  count_steps {
309    SELECT coalesce(t2.a,9999)
310      FROM t1 LEFT JOIN t2 ON (t1.c=t2.c AND t1.d=t2.d) OR t1.f=t2.f
311     WHERE t1.a=80
312    ORDER BY 1
313  }
314} {2 28 54 80 scan 0 sort 1}
315do_test where9-2.4 {
316  count_steps {
317    SELECT coalesce(t2.a,9999)
318      FROM t1 LEFT JOIN t2 ON (t1.c+1=t2.c AND t1.d=t2.d) OR (t1.f||'x')=t2.f
319     WHERE t1.a=80
320    ORDER BY 1
321  }
322} {9999 scan 0 sort 1}
323do_test where9-2.5 {
324  count_steps {
325    SELECT t1.a, coalesce(t2.a,9999)
326      FROM t1 LEFT JOIN t2 ON (t1.c=t2.c AND t1.d=t2.d) OR (t1.f)=t2.f
327     WHERE t1.a=80 OR t1.b=880 OR (t1.c=27027 AND round(t1.d)==80)
328    ORDER BY 1
329  }
330} {80 80 80 2 80 28 80 54 scan 0 sort 1}
331do_test where9-2.6 {
332  count_steps {
333    SELECT t1.a, coalesce(t2.a,9999)
334      FROM t1 LEFT JOIN t2 ON (t1.c+1=t2.c AND t1.d=t2.d) OR (t1.f||'x')=t2.f
335     WHERE t1.a=80 OR t1.b=880 OR (t1.c=27027 AND round(t1.d)==80)
336    ORDER BY 1
337  }
338} {80 9999 scan 0 sort 1}
339do_test where9-2.7 {
340  count_steps {
341    SELECT t3.x, t1.a, coalesce(t2.a,9999)
342      FROM t3 JOIN
343           t1 LEFT JOIN t2 ON (t1.c+1=t2.c AND t1.d=t2.d) OR (t1.f||'x')=t2.f
344     WHERE t1.a=t3.y OR t1.b=t3.y*11 OR (t1.c=27027 AND round(t1.d)==80)
345    ORDER BY 1, 2
346  }
347} {1 80 9999 2 80 9999 scan 1 sort 1}
348do_test where9-2.8 {
349  count_steps {
350    SELECT t3.x, t1.a, coalesce(t2.a,9999)
351      FROM t3 JOIN
352           t1 LEFT JOIN t2 ON (t1.c=t2.c AND t1.d=t2.d) OR (t1.f)=t2.f
353     WHERE t1.a=t3.y OR t1.b=t3.y*11 OR (t1.c=27027 AND round(t1.d)==80)
354    ORDER BY 1, 2, 3
355  }
356} {1 80 2 1 80 28 1 80 54 1 80 80 2 80 2 2 80 28 2 80 54 2 80 80 scan 1 sort 1}
357
358
359ifcapable explain {
360  do_eqp_test where9-3.1 {
361    SELECT t2.a FROM t1, t2
362    WHERE t1.a=80 AND ((t1.c=t2.c AND t1.d=t2.d) OR t1.f=t2.f)
363  } [string map {"\n  " \n} {
364    QUERY PLAN
365    |--SEARCH TABLE t1 USING INTEGER PRIMARY KEY (rowid=?)
366    `--MULTI-INDEX OR
367       |--SEARCH TABLE t2 USING INDEX t2d (d=?)
368       `--SEARCH TABLE t2 USING COVERING INDEX t2f (f=?)
369  }]
370  do_eqp_test where9-3.2 {
371    SELECT coalesce(t2.a,9999)
372    FROM t1 LEFT JOIN t2 ON (t1.c+1=t2.c AND t1.d=t2.d) OR (t1.f||'x')=t2.f
373    WHERE t1.a=80
374  } [string map {"\n  " \n} {
375    QUERY PLAN
376    |--SEARCH TABLE t1 USING INTEGER PRIMARY KEY (rowid=?)
377    `--MULTI-INDEX OR
378       |--SEARCH TABLE t2 USING INDEX t2d (d=?)
379       `--SEARCH TABLE t2 USING COVERING INDEX t2f (f=?)
380  }]
381}
382
383# Make sure that INDEXED BY and multi-index OR clauses play well with
384# one another.
385#
386do_test where9-4.1 {
387  count_steps {
388    SELECT a FROM t1
389     WHERE b>1000
390       AND (c=31031 OR d IS NULL)
391     ORDER BY +a
392  }
393} {92 93 97 scan 0 sort 1}
394do_test where9-4.2 {
395  count_steps {
396    SELECT a FROM t1
397     WHERE b>1000
398       AND (c=31031 OR +d IS NULL)
399     ORDER BY +a
400  }
401} {92 93 97 scan 0 sort 1}
402do_test where9-4.3 {
403  count_steps {
404    SELECT a FROM t1
405     WHERE +b>1000
406       AND (c=31031 OR d IS NULL)
407     ORDER BY +a
408  }
409} {92 93 97 scan 0 sort 1}
410do_test where9-4.4 {
411  count_steps {
412    SELECT a FROM t1 INDEXED BY t1b
413     WHERE b>1000
414       AND (c=31031 OR d IS NULL)
415     ORDER BY +a
416  }
417} {92 93 97 scan 0 sort 1}
418do_test where9-4.5 {
419  catchsql {
420    SELECT a FROM t1 INDEXED BY t1b
421     WHERE +b>1000
422       AND (c=31031 OR d IS NULL)
423     ORDER BY +a
424  }
425} {1 {no query solution}}
426do_test where9-4.6 {
427  count_steps {
428    SELECT a FROM t1 NOT INDEXED
429     WHERE b>1000
430       AND (c=31031 OR d IS NULL)
431     ORDER BY +a
432  }
433} {92 93 97 scan 98 sort 1}
434do_test where9-4.7 {
435  catchsql {
436    SELECT a FROM t1 INDEXED BY t1c
437     WHERE b>1000
438       AND (c=31031 OR d IS NULL)
439     ORDER BY +a
440  }
441} {1 {no query solution}}
442do_test where9-4.8 {
443  catchsql {
444    SELECT a FROM t1 INDEXED BY t1d
445     WHERE b>1000
446       AND (c=31031 OR d IS NULL)
447     ORDER BY +a
448  }
449} {1 {no query solution}}
450
451# The (c=31031 OR d IS NULL) clause is preferred over b>1000 because
452# the former is an equality test which is expected to return fewer rows.
453#
454do_eqp_test where9-5.1 {
455  SELECT a FROM t1 WHERE b>1000 AND (c=31031 OR d IS NULL)
456} {
457  QUERY PLAN
458  `--MULTI-INDEX OR
459     |--SEARCH TABLE t1 USING INDEX t1c (c=?)
460     `--SEARCH TABLE t1 USING INDEX t1d (d=?)
461}
462
463# In contrast, b=1000 is preferred over any OR-clause.
464#
465do_eqp_test where9-5.2 {
466  SELECT a FROM t1 WHERE b=1000 AND (c=31031 OR d IS NULL)
467} {SEARCH TABLE t1 USING INDEX t1b (b=?)}
468
469# Likewise, inequalities in an AND are preferred over inequalities in
470# an OR.
471#
472do_eqp_test where9-5.3 {
473  SELECT a FROM t1 WHERE b>1000 AND (c>=31031 OR d IS NULL)
474} {SEARCH TABLE t1 USING INDEX t1b (b>?)}
475
476############################################################################
477# Make sure OR-clauses work correctly on UPDATE and DELETE statements.
478
479do_test where9-6.2.1 {
480  db eval {SELECT count(*) FROM t1 UNION ALL SELECT a FROM t1 WHERE a>=85}
481} {99 85 86 87 88 89 90 91 92 93 94 95 96 97 98 99}
482
483do_test where9-6.2.2 {   ;# Deletes entries 90 91 92 96 97 99
484  count_steps {
485     BEGIN;
486     DELETE FROM t1
487     WHERE b IS NULL
488        OR c IS NULL
489        OR d IS NULL
490  }
491} {scan 0 sort 0}
492
493do_test where9-6.2.3 {
494  db eval {
495    SELECT count(*) FROM t1 UNION ALL
496    SELECT a FROM t1 WHERE a>=85;
497    ROLLBACK;
498  }
499} {93 85 86 87 88 89 93 94 95 98}
500
501do_test where9-6.2.4 {   ;# Deletes entries 90 91 92 96 97 99
502  count_steps {
503     BEGIN;
504     DELETE FROM t1
505     WHERE +b IS NULL
506        OR c IS NULL
507        OR d IS NULL
508  }
509} {scan 98 sort 0}
510
511do_test where9-6.2.5 {
512  db eval {
513     SELECT count(*) FROM t1 UNION ALL
514     SELECT a FROM t1 WHERE a>=85;
515     ROLLBACK;
516  }
517} {93 85 86 87 88 89 93 94 95 98}
518
519do_test where9-6.2.6 {
520  count_steps {
521     BEGIN;
522     UPDATE t1 SET a=a+100
523     WHERE (b IS NULL
524            OR c IS NULL
525            OR d IS NULL)
526       AND a!=92
527       AND a!=97
528  }
529} {scan 0 sort 0}   ;# Add 100 to entries 90 91 96 99
530
531do_test where9-6.2.7 {
532  db eval {
533     SELECT count(*) FROM t1 UNION ALL
534     SELECT a FROM t1 WHERE a>=85;
535     ROLLBACK
536  }
537} {99 85 86 87 88 89 92 93 94 95 97 98 190 191 196 199}
538
539do_test where9-6.2.8 {   ;# Deletes entries 90 91 92 97 99
540  count_steps {
541     BEGIN;
542     DELETE FROM t1
543     WHERE (b IS NULL
544            OR c IS NULL
545            OR d IS NULL)
546       AND a!=96
547  }
548} {scan 0 sort 0}
549
550do_test where9-6.2.9 {
551  db eval {
552     SELECT count(*) FROM t1 UNION ALL SELECT a FROM t1 WHERE a>=85;
553     ROLLBACK;
554  }
555} {94 85 86 87 88 89 93 94 95 96 98}
556
557do_test where9-6.3.1 {
558  count_steps {
559    BEGIN;
560    DELETE FROM t1
561     WHERE (b IS NULL AND c NOT NULL AND d NOT NULL)
562        OR (b NOT NULL AND c IS NULL AND d NOT NULL)
563        OR (b NOT NULL AND c NOT NULL AND d IS NULL)
564  }
565} {scan 0 sort 0}   ;# DELETEs rows 90 91 92 97
566do_test where9-6.3.2 {
567  db eval {
568    SELECT count(*) FROM t1 UNION ALL
569    SELECT a FROM t1 WHERE a BETWEEN 85 AND 100;
570    ROLLBACK;
571  }
572} {95 85 86 87 88 89 93 94 95 96 98 99}
573
574do_test where9-6.3.3 {
575  count_steps {
576    BEGIN;
577    UPDATE t1 SET a=a+100
578     WHERE (b IS NULL AND c NOT NULL AND d NOT NULL)
579        OR (b NOT NULL AND c IS NULL AND d NOT NULL)
580        OR (b NOT NULL AND c NOT NULL AND d IS NULL)
581  }
582} {scan 0 sort 0}   ;# Add 100 to rowids 90 91 92 97
583do_test where9-6.3.4 {
584  db eval {
585    SELECT count(*) FROM t1 UNION ALL
586    SELECT a FROM t1 WHERE a BETWEEN 85 AND 200;
587    ROLLBACK;
588  }
589} {99 85 86 87 88 89 93 94 95 96 98 99 190 191 192 197}
590
591do_test where9-6.3.5 {
592  count_steps {
593    BEGIN;
594    DELETE FROM t1
595     WHERE (+b IS NULL AND c NOT NULL AND d NOT NULL)
596        OR (b NOT NULL AND c IS NULL AND d NOT NULL)
597        OR (b NOT NULL AND c NOT NULL AND d IS NULL)
598  }
599} {scan 98 sort 0}   ;# DELETEs rows 90 91 92 97
600do_test where9-6.3.6 {
601  db eval {
602    SELECT count(*) FROM t1 UNION ALL
603    SELECT a FROM t1 WHERE a BETWEEN 85 AND 100;
604    ROLLBACK;
605  }
606} {95 85 86 87 88 89 93 94 95 96 98 99}
607
608do_test where9-6.3.7 {
609  count_steps {
610    BEGIN;
611    UPDATE t1 SET a=a+100
612     WHERE (b IS NULL AND c NOT NULL AND d NOT NULL)
613        OR (b NOT NULL AND +c IS NULL AND d NOT NULL)
614        OR (b NOT NULL AND c NOT NULL AND d IS NULL)
615  }
616} {scan 98 sort 0}   ;# Add 100 to rowids 90 91 92 97
617do_test where9-6.3.8 {
618  db eval {
619    SELECT count(*) FROM t1 UNION ALL
620    SELECT a FROM t1 WHERE a BETWEEN 85 AND 100;
621    ROLLBACK;
622  }
623} {99 85 86 87 88 89 93 94 95 96 98 99}
624
625
626do_test where9-6.4.1 {
627  count_steps {
628    BEGIN;
629    DELETE FROM t1
630     WHERE (b>=950 AND b<=1010) OR (b IS NULL AND c NOT NULL)
631  }
632} {scan 0 sort 0}  ;# DELETE rows 87 88 89 90 91
633do_test where9-6.4.2 {
634  db eval {
635    SELECT count(*) FROM t1 UNION ALL
636    SELECT a FROM t1 WHERE a BETWEEN 85 AND 100;
637    ROLLBACK;
638  }
639} {94 85 86 92 93 94 95 96 97 98 99}
640do_test where9-6.4.3 {
641  count_steps {
642    BEGIN;
643    UPDATE t1 SET a=a+100
644     WHERE (b>=950 AND b<=1010) OR (b IS NULL AND c NOT NULL)
645  }
646} {scan 0 sort 0}  ;# Add 100 to rowids 87 88 89 90 91
647do_test where9-6.4.4 {
648  db eval {
649    SELECT count(*) FROM t1 UNION ALL
650    SELECT a FROM t1 WHERE a BETWEEN 85 AND 100;
651    ROLLBACK;
652  }
653} {99 85 86 92 93 94 95 96 97 98 99}
654
655
656do_test where9-6.5.1 {
657  count_steps {
658    BEGIN;
659    DELETE FROM t1
660     WHERE a=83
661        OR b=913
662        OR c=28028
663        OR (d>=82 AND d<83)
664        OR (e>2802 AND e<2803)
665        OR f='fghijklmn'
666        OR g='hgfedcb'
667  }
668} {scan 0 sort 0}   ;#  DELETE rows 5 31 57 82 83 84 85 86 87
669do_test where9-6.5.2 {
670  db eval {
671    SELECT count(*) FROM t1 UNION ALL
672    SELECT a FROM t1 WHERE a IN (5,31,57,82,83,84,85,86,87);
673    ROLLBACK;
674  }
675} {90}
676
677do_test where9-6.5.3 {
678  count_steps {
679    BEGIN;
680    UPDATE t1 SET a=a+100
681     WHERE a=83
682        OR b=913
683        OR c=28028
684        OR (d>=82 AND d<83)
685        OR (e>2802 AND e<2803)
686        OR f='fghijklmn'
687        OR g='hgfedcb'
688  }
689} {scan 0 sort 0}   ;#  Add 100 to rowids 5 31 57 82 83 84 85 86 87
690do_test where9-6.5.4 {
691  db eval {
692    SELECT count(*) FROM t1 UNION ALL
693    SELECT a FROM t1 WHERE a%100 IN (5,31,57,82,83,84,85,86,87) ORDER BY rowid;
694    ROLLBACK;
695  }
696} {99 105 131 157 182 183 184 185 186 187}
697
698do_test where9-6.6.1 {
699  count_steps {
700    BEGIN;
701    DELETE FROM t1
702     WHERE (b IS NULL AND c NOT NULL AND d NOT NULL)
703        OR (b NOT NULL AND +c IS NULL AND d NOT NULL)
704        OR (b NOT NULL AND c NOT NULL AND d IS NULL)
705  }
706} {scan 98 sort 0}   ;# DELETEs rows 90 91 92 97
707do_test where9-6.6.2 {
708  db eval {
709    SELECT count(*) FROM t1 UNION ALL
710    SELECT a FROM t1 WHERE a BETWEEN 85 AND 100;
711    ROLLBACK;
712  }
713} {95 85 86 87 88 89 93 94 95 96 98 99}
714
715do_test where9-6.6.3 {
716  count_steps {
717    BEGIN;
718    UPDATE t1 SET a=a+100
719     WHERE (b IS NULL AND c NOT NULL AND d NOT NULL)
720        OR (b NOT NULL AND +c IS NULL AND d NOT NULL)
721        OR (b NOT NULL AND c NOT NULL AND d IS NULL)
722  }
723} {scan 98 sort 0}   ;# Add 100 to rowids 90 91 92 97
724do_test where9-6.6.4 {
725  db eval {
726    SELECT count(*) FROM t1 UNION ALL
727    SELECT a FROM t1 WHERE a BETWEEN 85 AND 200;
728    ROLLBACK;
729  }
730} {99 85 86 87 88 89 93 94 95 96 98 99 190 191 192 197}
731
732do_test where9-6.7.1 {
733  count_steps {
734    BEGIN;
735    DELETE FROM t1 NOT INDEXED
736     WHERE (b IS NULL AND c NOT NULL AND d NOT NULL)
737        OR (b NOT NULL AND c IS NULL AND d NOT NULL)
738        OR (b NOT NULL AND c NOT NULL AND d IS NULL)
739  }
740} {scan 98 sort 0}   ;# DELETEs rows 90 91 92 97
741do_test where9-6.7.2 {
742  db eval {
743    SELECT count(*) FROM t1 UNION ALL
744    SELECT a FROM t1 WHERE a BETWEEN 85 AND 100;
745    ROLLBACK;
746  }
747} {95 85 86 87 88 89 93 94 95 96 98 99}
748
749do_test where9-6.7.3 {
750  count_steps {
751    BEGIN;
752    UPDATE t1 NOT INDEXED SET a=a+100
753     WHERE (b IS NULL AND c NOT NULL AND d NOT NULL)
754        OR (b NOT NULL AND c IS NULL AND d NOT NULL)
755        OR (b NOT NULL AND c NOT NULL AND d IS NULL)
756  }
757} {scan 98 sort 0}   ;# Add 100 to rowids 90 91 92 97
758do_test where9-6.7.4 {
759  db eval {
760    SELECT count(*) FROM t1 UNION ALL
761    SELECT a FROM t1 WHERE a BETWEEN 85 AND 200;
762    ROLLBACK;
763  }
764} {99 85 86 87 88 89 93 94 95 96 98 99 190 191 192 197}
765
766do_test where9-6.8.1 {
767  catchsql {
768    DELETE FROM t1 INDEXED BY t1b
769     WHERE (+b IS NULL AND c NOT NULL AND d NOT NULL)
770        OR (b NOT NULL AND c IS NULL AND d NOT NULL)
771        OR (b NOT NULL AND c NOT NULL AND d IS NULL)
772  }
773} {1 {no query solution}}
774do_test where9-6.8.2 {
775  catchsql {
776    UPDATE t1 INDEXED BY t1b SET a=a+100
777     WHERE (+b IS NULL AND c NOT NULL AND d NOT NULL)
778        OR (b NOT NULL AND c IS NULL AND d NOT NULL)
779        OR (b NOT NULL AND c NOT NULL AND d IS NULL)
780  }
781} {1 {no query solution}}
782
783set solution_possible 0
784ifcapable stat4||stat3 {
785  if {[permutation] != "no_optimization"} { set solution_possible 1 }
786}
787if $solution_possible {
788  # When STAT3 is enabled, the "b NOT NULL" terms get translated
789  # into b>NULL, which can be satified by the index t1b.  It is a very
790  # expensive way to do the query, but it works, and so a solution is possible.
791  do_test where9-6.8.3-stat4 {
792    catchsql {
793      UPDATE t1 INDEXED BY t1b SET a=a+100
794       WHERE (b IS NULL AND c NOT NULL AND d NOT NULL)
795          OR (b NOT NULL AND c IS NULL AND d NOT NULL)
796          OR (b NOT NULL AND c NOT NULL AND d IS NULL)
797    }
798  } {0 {}}
799  do_test where9-6.8.4-stat4 {
800    catchsql {
801      DELETE FROM t1 INDEXED BY t1b
802       WHERE (b IS NULL AND c NOT NULL AND d NOT NULL)
803          OR (b NOT NULL AND c IS NULL AND d NOT NULL)
804          OR (b NOT NULL AND c NOT NULL AND d IS NULL)
805    }
806  } {0 {}}
807} else {
808  do_test where9-6.8.3 {
809    catchsql {
810      UPDATE t1 INDEXED BY t1b SET a=a+100
811       WHERE (b IS NULL AND c NOT NULL AND d NOT NULL)
812          OR (b NOT NULL AND c IS NULL AND d NOT NULL)
813          OR (b NOT NULL AND c NOT NULL AND d IS NULL)
814    }
815  } {1 {no query solution}}
816  do_test where9-6.8.4 {
817    catchsql {
818      DELETE FROM t1 INDEXED BY t1b
819       WHERE (b IS NULL AND c NOT NULL AND d NOT NULL)
820          OR (b NOT NULL AND c IS NULL AND d NOT NULL)
821          OR (b NOT NULL AND c NOT NULL AND d IS NULL)
822    }
823  } {1 {no query solution}}
824}
825############################################################################
826# Test cases where terms inside an OR series are combined with AND terms
827# external to the OR clause.  In other words, cases where
828#
829#              x AND (y OR z)
830#
831# is able to use indices on x,y and x,z, or indices y,x and z,x.
832#
833do_test where9-7.0 {
834  execsql {
835    CREATE TABLE t5(a, b, c, d, e, f, g, x, y);
836    INSERT INTO t5
837     SELECT a, b, c, e, d, f, g,
838            CASE WHEN (a&1)!=0 THEN 'y' ELSE 'n' END,
839            CASE WHEN (a&2)!=0 THEN 'y' ELSE 'n' END
840       FROM t1;
841    CREATE INDEX t5xb ON t5(x, b);
842    CREATE INDEX t5xc ON t5(x, c);
843    CREATE INDEX t5xd ON t5(x, d);
844    CREATE INDEX t5xe ON t5(x, e);
845    CREATE INDEX t5xf ON t5(x, f);
846    CREATE INDEX t5xg ON t5(x, g);
847    CREATE INDEX t5yb ON t5(y, b);
848    CREATE INDEX t5yc ON t5(y, c);
849    CREATE INDEX t5yd ON t5(y, d);
850    CREATE INDEX t5ye ON t5(y, e);
851    CREATE INDEX t5yf ON t5(y, f);
852    CREATE INDEX t5yg ON t5(y, g);
853    CREATE TABLE t6(a, b, c, e, d, f, g, x, y);
854    INSERT INTO t6 SELECT * FROM t5;
855    ANALYZE t5;
856  }
857  ifcapable stat3 {
858    sqlite3 db2 test.db
859    db2 eval { DROP TABLE IF EXISTS sqlite_stat3 }
860    db2 close
861  }
862} {}
863do_test where9-7.1.1 {
864  count_steps {
865    SELECT a FROM t5 WHERE x='y' AND (b=913 OR c=27027) ORDER BY a;
866  }
867} {79 81 83 scan 0 sort 1}
868do_test where9-7.1.2 {
869  execsql {
870    SELECT a FROM t6 WHERE x='y' AND (b=913 OR c=27027) ORDER BY a;
871  }
872} {79 81 83}
873do_test where9-7.1.3 {
874  count_steps {
875    SELECT a FROM t5 WHERE x='n' AND (b=913 OR c=27027) ORDER BY a;
876  }
877} {80 scan 0 sort 1}
878do_test where9-7.1.4 {
879  execsql {
880    SELECT a FROM t6 WHERE x='n' AND (b=913 OR c=27027) ORDER BY a;
881  }
882} {80}
883do_test where9-7.2.1 {
884  count_steps {
885    SELECT a FROM t5 WHERE (x='y' OR y='y') AND b=913 ORDER BY a;
886  }
887} {83 scan 0 sort 1}
888do_test where9-7.2.2 {
889  execsql {
890    SELECT a FROM t6 WHERE (x='y' OR y='y') AND b=913 ORDER BY a;
891  }
892} {83}
893do_test where9-7.3.1 {
894  count_steps {
895    SELECT a FROM t5 WHERE (x='y' OR y='y') AND c=27027 ORDER BY a;
896  }
897} {79 81 scan 0 sort 1}
898do_test where9-7.3.2 {
899  execsql {
900    SELECT a FROM t6 WHERE (x='y' OR y='y') AND c=27027 ORDER BY a;
901  }
902} {79 81}
903
904# Fix for ticket [b7c8682cc17f32903f03a610bd0d35ffd3c1e6e4]
905# "Incorrect result from LEFT JOIN with OR in the WHERE clause"
906#
907do_test where9-8.1 {
908  db eval {
909    CREATE TABLE t81(a INTEGER PRIMARY KEY, b, c, d);
910    CREATE TABLE t82(x INTEGER PRIMARY KEY, y);
911    CREATE TABLE t83(p INTEGER PRIMARY KEY, q);
912
913    INSERT INTO t81 VALUES(2,3,4,5);
914    INSERT INTO t81 VALUES(3,4,5,6);
915    INSERT INTO t82 VALUES(2,4);
916    INSERT INTO t83 VALUES(5,55);
917
918    SELECT *
919      FROM t81 LEFT JOIN t82 ON y=b JOIN t83
920     WHERE c==p OR d==p
921     ORDER BY +a;
922  }
923} {2 3 4 5 {} {} 5 55 3 4 5 6 2 4 5 55}
924do_test where9-8.2 {
925  db eval {
926    SELECT *
927      FROM t81 LEFT JOIN (t82) ON y=b JOIN t83
928     WHERE c==p OR d==p
929     ORDER BY +a;
930  }
931} {2 3 4 5 {} {} 5 55 3 4 5 6 2 4 5 55}
932do_test where9-8.3 {
933  db eval {
934    SELECT *
935      FROM (t81) LEFT JOIN (main.t82) ON y=b JOIN t83
936     WHERE c==p OR d==p
937     ORDER BY +a;
938  }
939} {2 3 4 5 {} {} 5 55 3 4 5 6 2 4 5 55}
940
941# Fix for ticket [f2369304e47167e3e644e2f1fe9736063391d7b7]
942# Incorrect results when OR is used in the ON clause of a LEFT JOIN
943#
944do_test where9-9.1 {
945  db eval {
946    CREATE TABLE t91(x); INSERT INTO t91 VALUES(1);
947    CREATE TABLE t92(y INTEGER PRIMARY KEY,a,b);
948    INSERT INTO t92 VALUES(1,2,3);
949    SELECT 1 FROM t91 LEFT JOIN t92 ON a=2 OR b=3;
950    SELECT 2 FROM t91 LEFT JOIN t92 ON a=2 AND b=3;
951    SELECT 3 FROM t91 LEFT JOIN t92 ON (a=2 OR b=3) AND y IS NULL;
952    SELECT 4 FROM t91 LEFT JOIN t92 ON (a=2 AND b=3) AND y IS NULL;
953    CREATE TEMP TABLE x9 AS SELECT * FROM t91 LEFT JOIN t92 ON a=2 OR b=3;
954    SELECT 5 FROM x9 WHERE y IS NULL;
955    SELECT 6 FROM t91 LEFT JOIN t92 ON a=2 OR b=3 WHERE y IS NULL;
956    SELECT 7 FROM t91 LEFT JOIN t92 ON a=2 AND b=3 WHERE y IS NULL;
957    SELECT 8 FROM t91 LEFT JOIN t92 ON a=22 OR b=33 WHERE y IS NULL;
958    SELECT 9 FROM t91 LEFT JOIN t92 ON a=22 AND b=33 WHERE y IS NULL;
959  }
960} {1 2 3 4 8 9}
961
962# Fix for ticket [bc878246eafe0f52c519e29049b2fe4a99491b27]
963# Incorrect result when OR is used in a join to the right of a LEFT JOIN
964#
965do_test where9-10.1 {
966  db eval {
967    CREATE TABLE t101 (id INTEGER PRIMARY KEY);
968    INSERT INTO t101 VALUES (1);
969    SELECT * FROM t101 AS t0
970         LEFT JOIN t101 AS t1 ON t1.id BETWEEN 10 AND 20
971         JOIN t101 AS t2 ON (t2.id = t0.id OR (t2.id<>555 AND t2.id=t1.id));
972  }
973} {1 {} 1}
974do_test where9-10.2 {
975  db eval {
976    CREATE TABLE t102 (id TEXT UNIQUE NOT NULL);
977    INSERT INTO t102 VALUES ('1');
978    SELECT * FROM t102 AS t0
979         LEFT JOIN t102 AS t1 ON t1.id GLOB 'abc%'
980         JOIN t102 AS t2 ON (t2.id = t0.id OR (t2.id<>555 AND t2.id=t1.id));
981  }
982} {1 {} 1}
983
984
985
986finish_test
987