xref: /sqlite-3.40.0/test/where9.test (revision c583719b)
146129af9Sdrh# 2008 December 30
246129af9Sdrh#
346129af9Sdrh# The author disclaims copyright to this source code.  In place of
446129af9Sdrh# a legal notice, here is a blessing:
546129af9Sdrh#
646129af9Sdrh#    May you do good and not evil.
746129af9Sdrh#    May you find forgiveness for yourself and forgive others.
846129af9Sdrh#    May you share freely, never taking more than you give.
946129af9Sdrh#
1046129af9Sdrh#***********************************************************************
1146129af9Sdrh# This file implements regression tests for SQLite library.  The
1246129af9Sdrh# focus of this file is testing the multi-index OR clause optimizer.
1346129af9Sdrh#
1446129af9Sdrh
1546129af9Sdrhset testdir [file dirname $argv0]
1646129af9Sdrhsource $testdir/tester.tcl
1746129af9Sdrh
182f56da3fSdanifcapable !or_opt||!compound {
1946129af9Sdrh  finish_test
2046129af9Sdrh  return
2146129af9Sdrh}
2246129af9Sdrh
2346129af9Sdrh# Evaluate SQL.  Return the result set followed by the
2446129af9Sdrh# and the number of full-scan steps.
2546129af9Sdrh#
2646129af9Sdrhproc count_steps {sql} {
2746129af9Sdrh  set r [db eval $sql]
2846129af9Sdrh  lappend r scan [db status step] sort [db status sort]
2946129af9Sdrh}
3046129af9Sdrh
3146129af9Sdrh
3246129af9Sdrh# Construct test data.
3346129af9Sdrh#
3446129af9Sdrhdo_test where9-1.1 {
3546129af9Sdrh  db eval {
3646129af9Sdrh    CREATE TABLE t1(a INTEGER PRIMARY KEY,b,c,d,e,f,g);
3746129af9Sdrh    INSERT INTO t1 VALUES(1,11,1001,1.001,100.1,'bcdefghij','yxwvuts');
3846129af9Sdrh    INSERT INTO t1 VALUES(2,22,1001,2.002,100.1,'cdefghijk','yxwvuts');
3946129af9Sdrh    INSERT INTO t1 VALUES(3,33,1001,3.003,100.1,'defghijkl','xwvutsr');
4046129af9Sdrh    INSERT INTO t1 VALUES(4,44,2002,4.004,200.2,'efghijklm','xwvutsr');
4146129af9Sdrh    INSERT INTO t1 VALUES(5,55,2002,5.005,200.2,'fghijklmn','xwvutsr');
4246129af9Sdrh    INSERT INTO t1 VALUES(6,66,2002,6.006,200.2,'ghijklmno','xwvutsr');
4346129af9Sdrh    INSERT INTO t1 VALUES(7,77,3003,7.007,300.3,'hijklmnop','xwvutsr');
4446129af9Sdrh    INSERT INTO t1 VALUES(8,88,3003,8.008,300.3,'ijklmnopq','wvutsrq');
4546129af9Sdrh    INSERT INTO t1 VALUES(9,99,3003,9.009,300.3,'jklmnopqr','wvutsrq');
4646129af9Sdrh    INSERT INTO t1 VALUES(10,110,4004,10.01,400.4,'klmnopqrs','wvutsrq');
4746129af9Sdrh    INSERT INTO t1 VALUES(11,121,4004,11.011,400.4,'lmnopqrst','wvutsrq');
4846129af9Sdrh    INSERT INTO t1 VALUES(12,132,4004,12.012,400.4,'mnopqrstu','wvutsrq');
4946129af9Sdrh    INSERT INTO t1 VALUES(13,143,5005,13.013,500.5,'nopqrstuv','vutsrqp');
5046129af9Sdrh    INSERT INTO t1 VALUES(14,154,5005,14.014,500.5,'opqrstuvw','vutsrqp');
5146129af9Sdrh    INSERT INTO t1 VALUES(15,165,5005,15.015,500.5,'pqrstuvwx','vutsrqp');
5246129af9Sdrh    INSERT INTO t1 VALUES(16,176,6006,16.016,600.6,'qrstuvwxy','vutsrqp');
5346129af9Sdrh    INSERT INTO t1 VALUES(17,187,6006,17.017,600.6,'rstuvwxyz','vutsrqp');
5446129af9Sdrh    INSERT INTO t1 VALUES(18,198,6006,18.018,600.6,'stuvwxyza','utsrqpo');
5546129af9Sdrh    INSERT INTO t1 VALUES(19,209,7007,19.019,700.7,'tuvwxyzab','utsrqpo');
5646129af9Sdrh    INSERT INTO t1 VALUES(20,220,7007,20.02,700.7,'uvwxyzabc','utsrqpo');
5746129af9Sdrh    INSERT INTO t1 VALUES(21,231,7007,21.021,700.7,'vwxyzabcd','utsrqpo');
5846129af9Sdrh    INSERT INTO t1 VALUES(22,242,8008,22.022,800.8,'wxyzabcde','utsrqpo');
5946129af9Sdrh    INSERT INTO t1 VALUES(23,253,8008,23.023,800.8,'xyzabcdef','tsrqpon');
6046129af9Sdrh    INSERT INTO t1 VALUES(24,264,8008,24.024,800.8,'yzabcdefg','tsrqpon');
6146129af9Sdrh    INSERT INTO t1 VALUES(25,275,9009,25.025,900.9,'zabcdefgh','tsrqpon');
6246129af9Sdrh    INSERT INTO t1 VALUES(26,286,9009,26.026,900.9,'abcdefghi','tsrqpon');
6346129af9Sdrh    INSERT INTO t1 VALUES(27,297,9009,27.027,900.9,'bcdefghij','tsrqpon');
6446129af9Sdrh    INSERT INTO t1 VALUES(28,308,10010,28.028,1001.0,'cdefghijk','srqponm');
6546129af9Sdrh    INSERT INTO t1 VALUES(29,319,10010,29.029,1001.0,'defghijkl','srqponm');
6646129af9Sdrh    INSERT INTO t1 VALUES(30,330,10010,30.03,1001.0,'efghijklm','srqponm');
6746129af9Sdrh    INSERT INTO t1 VALUES(31,341,11011,31.031,1101.1,'fghijklmn','srqponm');
6846129af9Sdrh    INSERT INTO t1 VALUES(32,352,11011,32.032,1101.1,'ghijklmno','srqponm');
6946129af9Sdrh    INSERT INTO t1 VALUES(33,363,11011,33.033,1101.1,'hijklmnop','rqponml');
7046129af9Sdrh    INSERT INTO t1 VALUES(34,374,12012,34.034,1201.2,'ijklmnopq','rqponml');
7146129af9Sdrh    INSERT INTO t1 VALUES(35,385,12012,35.035,1201.2,'jklmnopqr','rqponml');
7246129af9Sdrh    INSERT INTO t1 VALUES(36,396,12012,36.036,1201.2,'klmnopqrs','rqponml');
7346129af9Sdrh    INSERT INTO t1 VALUES(37,407,13013,37.037,1301.3,'lmnopqrst','rqponml');
7446129af9Sdrh    INSERT INTO t1 VALUES(38,418,13013,38.038,1301.3,'mnopqrstu','qponmlk');
7546129af9Sdrh    INSERT INTO t1 VALUES(39,429,13013,39.039,1301.3,'nopqrstuv','qponmlk');
7646129af9Sdrh    INSERT INTO t1 VALUES(40,440,14014,40.04,1401.4,'opqrstuvw','qponmlk');
7746129af9Sdrh    INSERT INTO t1 VALUES(41,451,14014,41.041,1401.4,'pqrstuvwx','qponmlk');
7846129af9Sdrh    INSERT INTO t1 VALUES(42,462,14014,42.042,1401.4,'qrstuvwxy','qponmlk');
7946129af9Sdrh    INSERT INTO t1 VALUES(43,473,15015,43.043,1501.5,'rstuvwxyz','ponmlkj');
8046129af9Sdrh    INSERT INTO t1 VALUES(44,484,15015,44.044,1501.5,'stuvwxyza','ponmlkj');
8146129af9Sdrh    INSERT INTO t1 VALUES(45,495,15015,45.045,1501.5,'tuvwxyzab','ponmlkj');
8246129af9Sdrh    INSERT INTO t1 VALUES(46,506,16016,46.046,1601.6,'uvwxyzabc','ponmlkj');
8346129af9Sdrh    INSERT INTO t1 VALUES(47,517,16016,47.047,1601.6,'vwxyzabcd','ponmlkj');
8446129af9Sdrh    INSERT INTO t1 VALUES(48,528,16016,48.048,1601.6,'wxyzabcde','onmlkji');
8546129af9Sdrh    INSERT INTO t1 VALUES(49,539,17017,49.049,1701.7,'xyzabcdef','onmlkji');
8646129af9Sdrh    INSERT INTO t1 VALUES(50,550,17017,50.05,1701.7,'yzabcdefg','onmlkji');
8746129af9Sdrh    INSERT INTO t1 VALUES(51,561,17017,51.051,1701.7,'zabcdefgh','onmlkji');
8846129af9Sdrh    INSERT INTO t1 VALUES(52,572,18018,52.052,1801.8,'abcdefghi','onmlkji');
8946129af9Sdrh    INSERT INTO t1 VALUES(53,583,18018,53.053,1801.8,'bcdefghij','nmlkjih');
9046129af9Sdrh    INSERT INTO t1 VALUES(54,594,18018,54.054,1801.8,'cdefghijk','nmlkjih');
9146129af9Sdrh    INSERT INTO t1 VALUES(55,605,19019,55.055,1901.9,'defghijkl','nmlkjih');
9246129af9Sdrh    INSERT INTO t1 VALUES(56,616,19019,56.056,1901.9,'efghijklm','nmlkjih');
9346129af9Sdrh    INSERT INTO t1 VALUES(57,627,19019,57.057,1901.9,'fghijklmn','nmlkjih');
9446129af9Sdrh    INSERT INTO t1 VALUES(58,638,20020,58.058,2002.0,'ghijklmno','mlkjihg');
9546129af9Sdrh    INSERT INTO t1 VALUES(59,649,20020,59.059,2002.0,'hijklmnop','mlkjihg');
9646129af9Sdrh    INSERT INTO t1 VALUES(60,660,20020,60.06,2002.0,'ijklmnopq','mlkjihg');
9746129af9Sdrh    INSERT INTO t1 VALUES(61,671,21021,61.061,2102.1,'jklmnopqr','mlkjihg');
9846129af9Sdrh    INSERT INTO t1 VALUES(62,682,21021,62.062,2102.1,'klmnopqrs','mlkjihg');
9946129af9Sdrh    INSERT INTO t1 VALUES(63,693,21021,63.063,2102.1,'lmnopqrst','lkjihgf');
10046129af9Sdrh    INSERT INTO t1 VALUES(64,704,22022,64.064,2202.2,'mnopqrstu','lkjihgf');
10146129af9Sdrh    INSERT INTO t1 VALUES(65,715,22022,65.065,2202.2,'nopqrstuv','lkjihgf');
10246129af9Sdrh    INSERT INTO t1 VALUES(66,726,22022,66.066,2202.2,'opqrstuvw','lkjihgf');
10346129af9Sdrh    INSERT INTO t1 VALUES(67,737,23023,67.067,2302.3,'pqrstuvwx','lkjihgf');
10446129af9Sdrh    INSERT INTO t1 VALUES(68,748,23023,68.068,2302.3,'qrstuvwxy','kjihgfe');
10546129af9Sdrh    INSERT INTO t1 VALUES(69,759,23023,69.069,2302.3,'rstuvwxyz','kjihgfe');
10646129af9Sdrh    INSERT INTO t1 VALUES(70,770,24024,70.07,2402.4,'stuvwxyza','kjihgfe');
10746129af9Sdrh    INSERT INTO t1 VALUES(71,781,24024,71.071,2402.4,'tuvwxyzab','kjihgfe');
10846129af9Sdrh    INSERT INTO t1 VALUES(72,792,24024,72.072,2402.4,'uvwxyzabc','kjihgfe');
10946129af9Sdrh    INSERT INTO t1 VALUES(73,803,25025,73.073,2502.5,'vwxyzabcd','jihgfed');
11046129af9Sdrh    INSERT INTO t1 VALUES(74,814,25025,74.074,2502.5,'wxyzabcde','jihgfed');
11146129af9Sdrh    INSERT INTO t1 VALUES(75,825,25025,75.075,2502.5,'xyzabcdef','jihgfed');
11246129af9Sdrh    INSERT INTO t1 VALUES(76,836,26026,76.076,2602.6,'yzabcdefg','jihgfed');
11346129af9Sdrh    INSERT INTO t1 VALUES(77,847,26026,77.077,2602.6,'zabcdefgh','jihgfed');
11446129af9Sdrh    INSERT INTO t1 VALUES(78,858,26026,78.078,2602.6,'abcdefghi','ihgfedc');
11546129af9Sdrh    INSERT INTO t1 VALUES(79,869,27027,79.079,2702.7,'bcdefghij','ihgfedc');
11646129af9Sdrh    INSERT INTO t1 VALUES(80,880,27027,80.08,2702.7,'cdefghijk','ihgfedc');
11746129af9Sdrh    INSERT INTO t1 VALUES(81,891,27027,81.081,2702.7,'defghijkl','ihgfedc');
11846129af9Sdrh    INSERT INTO t1 VALUES(82,902,28028,82.082,2802.8,'efghijklm','ihgfedc');
11946129af9Sdrh    INSERT INTO t1 VALUES(83,913,28028,83.083,2802.8,'fghijklmn','hgfedcb');
12046129af9Sdrh    INSERT INTO t1 VALUES(84,924,28028,84.084,2802.8,'ghijklmno','hgfedcb');
12146129af9Sdrh    INSERT INTO t1 VALUES(85,935,29029,85.085,2902.9,'hijklmnop','hgfedcb');
12246129af9Sdrh    INSERT INTO t1 VALUES(86,946,29029,86.086,2902.9,'ijklmnopq','hgfedcb');
12346129af9Sdrh    INSERT INTO t1 VALUES(87,957,29029,87.087,2902.9,'jklmnopqr','hgfedcb');
12446129af9Sdrh    INSERT INTO t1 VALUES(88,968,30030,88.088,3003.0,'klmnopqrs','gfedcba');
12546129af9Sdrh    INSERT INTO t1 VALUES(89,979,30030,89.089,3003.0,'lmnopqrst','gfedcba');
12646129af9Sdrh    INSERT INTO t1 VALUES(90,NULL,30030,90.09,3003.0,'mnopqrstu','gfedcba');
12746129af9Sdrh    INSERT INTO t1 VALUES(91,1001,NULL,91.091,3103.1,'nopqrstuv','gfedcba');
12846129af9Sdrh    INSERT INTO t1 VALUES(92,1012,31031,NULL,3103.1,'opqrstuvw','gfedcba');
12946129af9Sdrh    INSERT INTO t1 VALUES(93,1023,31031,93.093,NULL,'pqrstuvwx','fedcbaz');
13046129af9Sdrh    INSERT INTO t1 VALUES(94,1034,32032,94.094,3203.2,NULL,'fedcbaz');
13146129af9Sdrh    INSERT INTO t1 VALUES(95,1045,32032,95.095,3203.2,'rstuvwxyz',NULL);
13246129af9Sdrh    INSERT INTO t1 VALUES(96,NULL,NULL,96.096,3203.2,'stuvwxyza','fedcbaz');
13346129af9Sdrh    INSERT INTO t1 VALUES(97,1067,33033,NULL,NULL,'tuvwxyzab','fedcbaz');
13446129af9Sdrh    INSERT INTO t1 VALUES(98,1078,33033,98.098,3303.3,NULL,NULL);
13546129af9Sdrh    INSERT INTO t1 VALUES(99,NULL,NULL,NULL,NULL,NULL,NULL);
13646129af9Sdrh    CREATE INDEX t1b ON t1(b);
13746129af9Sdrh    CREATE INDEX t1c ON t1(c);
13846129af9Sdrh    CREATE INDEX t1d ON t1(d);
13946129af9Sdrh    CREATE INDEX t1e ON t1(e);
14046129af9Sdrh    CREATE INDEX t1f ON t1(f);
14146129af9Sdrh    CREATE INDEX t1g ON t1(g);
14246129af9Sdrh    CREATE TABLE t2(a INTEGER PRIMARY KEY,b,c,d,e,f,g);
14346129af9Sdrh    INSERT INTO t2 SELECT * FROM t1;
14446129af9Sdrh    CREATE INDEX t2b ON t2(b,c);
14546129af9Sdrh    CREATE INDEX t2c ON t2(c,e);
14646129af9Sdrh    CREATE INDEX t2d ON t2(d,g);
14746129af9Sdrh    CREATE INDEX t2e ON t2(e,f,g);
14846129af9Sdrh    CREATE INDEX t2f ON t2(f,b,d,c);
14946129af9Sdrh    CREATE INDEX t2g ON t2(g,f);
150eb9441ebSdrh    CREATE TABLE t3(x,y);
151eb9441ebSdrh    INSERT INTO t3 VALUES(1,80);
152eb9441ebSdrh    INSERT INTO t3 VALUES(2,80);
153103bd88cSdrh    CREATE TABLE t4(a INTEGER PRIMARY KEY,b,c,d,e,f,g);
154103bd88cSdrh    INSERT INTO t4 SELECT * FROM t1;
155103bd88cSdrh    CREATE INDEX t4b ON t4(b);
156103bd88cSdrh    CREATE INDEX t4c ON t4(c);
15746129af9Sdrh  }
15846129af9Sdrh} {}
15946129af9Sdrh
16046129af9Sdrhdo_test where9-1.2.1 {
16146129af9Sdrh  count_steps {
16246129af9Sdrh    SELECT a FROM t1
16346129af9Sdrh     WHERE b IS NULL
16446129af9Sdrh        OR c IS NULL
16546129af9Sdrh        OR d IS NULL
16646129af9Sdrh    ORDER BY a
16746129af9Sdrh  }
1681d46146bSdanielk1977} {90 91 92 96 97 99 scan 0 sort 1}
16946129af9Sdrhdo_test where9-1.2.2 {
17046129af9Sdrh  count_steps {
17146129af9Sdrh    SELECT a FROM t1
17246129af9Sdrh     WHERE +b IS NULL
17346129af9Sdrh        OR c IS NULL
17446129af9Sdrh        OR d IS NULL
17546129af9Sdrh    ORDER BY a
17646129af9Sdrh  }
17746129af9Sdrh} {90 91 92 96 97 99 scan 98 sort 0}
17846129af9Sdrhdo_test where9-1.2.3 {
17946129af9Sdrh  count_steps {
18046129af9Sdrh    SELECT a FROM t1
18146129af9Sdrh     WHERE b IS NULL
18246129af9Sdrh        OR +c IS NULL
18346129af9Sdrh        OR d IS NULL
18446129af9Sdrh    ORDER BY a
18546129af9Sdrh  }
18646129af9Sdrh} {90 91 92 96 97 99 scan 98 sort 0}
18746129af9Sdrhdo_test where9-1.2.4 {
18846129af9Sdrh  count_steps {
18946129af9Sdrh    SELECT a FROM t1
19046129af9Sdrh     WHERE b IS NULL
19146129af9Sdrh        OR c IS NULL
19246129af9Sdrh        OR +d IS NULL
19346129af9Sdrh    ORDER BY a
19446129af9Sdrh  }
19546129af9Sdrh} {90 91 92 96 97 99 scan 98 sort 0}
196103bd88cSdrhdo_test where9-1.2.5 {
197103bd88cSdrh  count_steps {
198103bd88cSdrh    SELECT a FROM t4
199103bd88cSdrh     WHERE b IS NULL
200103bd88cSdrh        OR c IS NULL
201103bd88cSdrh        OR d IS NULL
202103bd88cSdrh    ORDER BY a
203103bd88cSdrh  }
204103bd88cSdrh} {90 91 92 96 97 99 scan 98 sort 0}
205103bd88cSdrh
206103bd88cSdrhdo_test where9-1.3.1 {
20746129af9Sdrh  count_steps {
20846129af9Sdrh    SELECT a FROM t1
20946129af9Sdrh     WHERE (b IS NULL AND c NOT NULL AND d NOT NULL)
21046129af9Sdrh        OR (b NOT NULL AND c IS NULL AND d NOT NULL)
21146129af9Sdrh        OR (b NOT NULL AND c NOT NULL AND d IS NULL)
21246129af9Sdrh    ORDER BY a
21346129af9Sdrh  }
2141d46146bSdanielk1977} {90 91 92 97 scan 0 sort 1}
215103bd88cSdrhdo_test where9-1.3.2 {
216103bd88cSdrh  count_steps {
217103bd88cSdrh    SELECT a FROM t4
218103bd88cSdrh     WHERE (b IS NULL AND c NOT NULL AND d NOT NULL)
219103bd88cSdrh        OR (b NOT NULL AND c IS NULL AND d NOT NULL)
220103bd88cSdrh        OR (b NOT NULL AND c NOT NULL AND d IS NULL)
221103bd88cSdrh    ORDER BY a
222103bd88cSdrh  }
223103bd88cSdrh} {90 91 92 97 scan 98 sort 0}
224103bd88cSdrhdo_test where9-1.3.3 {
225103bd88cSdrh  count_steps {
226103bd88cSdrh    SELECT a FROM t4
227103bd88cSdrh     WHERE (b NOT NULL AND c NOT NULL AND d IS NULL)
228103bd88cSdrh        OR (b IS NULL AND c NOT NULL AND d NOT NULL)
229103bd88cSdrh        OR (b NOT NULL AND c IS NULL AND d NOT NULL)
230103bd88cSdrh    ORDER BY a
231103bd88cSdrh  }
232103bd88cSdrh} {90 91 92 97 scan 98 sort 0}
233103bd88cSdrhdo_test where9-1.3.4 {
234103bd88cSdrh  count_steps {
235832ee3d4Sdrh    SELECT a FROM (t4)
236103bd88cSdrh     WHERE (b IS NULL AND c NOT NULL AND d NOT NULL)
237103bd88cSdrh        OR (b NOT NULL AND c NOT NULL AND d IS NULL)
238103bd88cSdrh        OR (b NOT NULL AND c IS NULL AND d NOT NULL)
239103bd88cSdrh    ORDER BY a
240103bd88cSdrh  }
241103bd88cSdrh} {90 91 92 97 scan 98 sort 0}
242103bd88cSdrh
24346129af9Sdrhdo_test where9-1.4 {
24446129af9Sdrh  count_steps {
24546129af9Sdrh    SELECT a FROM t1
24646129af9Sdrh     WHERE (b>=950 AND b<=1010) OR (b IS NULL AND c NOT NULL)
24746129af9Sdrh    ORDER BY a
24846129af9Sdrh  }
2491d46146bSdanielk1977} {87 88 89 90 91 scan 0 sort 1}
25046129af9Sdrhdo_test where9-1.5 {
2511d46146bSdanielk1977  # When this test was originally written, SQLite used a rowset object
2521d46146bSdanielk1977  # to optimize the "ORDER BY a" clause. Now that it is using a rowhash,
2531d46146bSdanielk1977  # this is not possible. So we have to comment out one term of the OR
2541d46146bSdanielk1977  # expression in order to prevent SQLite from deeming a full-table
2551d46146bSdanielk1977  # scan to be a better strategy than using multiple indexes, which would
2561d46146bSdanielk1977  # defeat the point of the test.
25746129af9Sdrh  count_steps {
25846129af9Sdrh    SELECT a FROM t1
25946129af9Sdrh     WHERE a=83
26046129af9Sdrh        OR b=913
26146129af9Sdrh        OR c=28028
26246129af9Sdrh        OR (d>=82 AND d<83)
2631d46146bSdanielk1977/*      OR (e>2802 AND e<2803)  */
26446129af9Sdrh        OR f='fghijklmn'
26546129af9Sdrh        OR g='hgfedcb'
26646129af9Sdrh    ORDER BY a
26746129af9Sdrh  }
2681d46146bSdanielk1977} {5 31 57 82 83 84 85 86 87 scan 0 sort 1}
26946129af9Sdrhdo_test where9-1.6 {
27046129af9Sdrh  count_steps {
27146129af9Sdrh    SELECT a FROM t1
27246129af9Sdrh     WHERE b=1012
27346129af9Sdrh        OR (d IS NULL AND e IS NOT NULL)
27446129af9Sdrh  }
27546129af9Sdrh} {92 scan 0 sort 0}
27646129af9Sdrhdo_test where9-1.7 {
27746129af9Sdrh  count_steps {
27846129af9Sdrh    SELECT a FROM t1
27946129af9Sdrh     WHERE (b=1012 OR (d IS NULL AND e IS NOT NULL))
28046129af9Sdrh       AND f!=g
28146129af9Sdrh  }
28246129af9Sdrh} {92 scan 0 sort 0}
28346129af9Sdrhdo_test where9-1.8 {
28446129af9Sdrh  count_steps {
28546129af9Sdrh    SELECT a FROM t1
28646129af9Sdrh     WHERE (b=1012 OR (d IS NULL AND e IS NOT NULL))
28746129af9Sdrh       AND f==g
28846129af9Sdrh  }
28946129af9Sdrh} {scan 0 sort 0}
29046129af9Sdrh
29146129af9Sdrhdo_test where9-2.1 {
29246129af9Sdrh  count_steps {
29346129af9Sdrh    SELECT t2.a FROM t1, t2
29446129af9Sdrh     WHERE t1.a=80
29546129af9Sdrh       AND (t1.c=t2.c OR t1.d=t2.d)
29646129af9Sdrh    ORDER BY 1
29746129af9Sdrh  }
29846129af9Sdrh} {79 80 81 scan 0 sort 1}
29946129af9Sdrhdo_test where9-2.2 {
30046129af9Sdrh  count_steps {
30146129af9Sdrh    SELECT t2.a FROM t1, t2
30246129af9Sdrh     WHERE t1.a=80
30346129af9Sdrh       AND ((t1.c=t2.c AND t1.d=t2.d) OR t1.f=t2.f)
30446129af9Sdrh    ORDER BY 1
30546129af9Sdrh  }
30646129af9Sdrh} {2 28 54 80 scan 0 sort 1}
30746129af9Sdrhdo_test where9-2.3 {
30846129af9Sdrh  count_steps {
30946129af9Sdrh    SELECT coalesce(t2.a,9999)
31046129af9Sdrh      FROM t1 LEFT JOIN t2 ON (t1.c=t2.c AND t1.d=t2.d) OR t1.f=t2.f
31146129af9Sdrh     WHERE t1.a=80
31246129af9Sdrh    ORDER BY 1
31346129af9Sdrh  }
31446129af9Sdrh} {2 28 54 80 scan 0 sort 1}
31546129af9Sdrhdo_test where9-2.4 {
31646129af9Sdrh  count_steps {
31746129af9Sdrh    SELECT coalesce(t2.a,9999)
31846129af9Sdrh      FROM t1 LEFT JOIN t2 ON (t1.c+1=t2.c AND t1.d=t2.d) OR (t1.f||'x')=t2.f
31946129af9Sdrh     WHERE t1.a=80
32046129af9Sdrh    ORDER BY 1
32146129af9Sdrh  }
32246129af9Sdrh} {9999 scan 0 sort 1}
323eb9441ebSdrhdo_test where9-2.5 {
324eb9441ebSdrh  count_steps {
325eb9441ebSdrh    SELECT t1.a, coalesce(t2.a,9999)
326eb9441ebSdrh      FROM t1 LEFT JOIN t2 ON (t1.c=t2.c AND t1.d=t2.d) OR (t1.f)=t2.f
327eb9441ebSdrh     WHERE t1.a=80 OR t1.b=880 OR (t1.c=27027 AND round(t1.d)==80)
328eb9441ebSdrh    ORDER BY 1
329eb9441ebSdrh  }
3301d46146bSdanielk1977} {80 80 80 2 80 28 80 54 scan 0 sort 1}
331eb9441ebSdrhdo_test where9-2.6 {
332eb9441ebSdrh  count_steps {
333eb9441ebSdrh    SELECT t1.a, coalesce(t2.a,9999)
334eb9441ebSdrh      FROM t1 LEFT JOIN t2 ON (t1.c+1=t2.c AND t1.d=t2.d) OR (t1.f||'x')=t2.f
335eb9441ebSdrh     WHERE t1.a=80 OR t1.b=880 OR (t1.c=27027 AND round(t1.d)==80)
336eb9441ebSdrh    ORDER BY 1
337eb9441ebSdrh  }
3381d46146bSdanielk1977} {80 9999 scan 0 sort 1}
339eb9441ebSdrhdo_test where9-2.7 {
340eb9441ebSdrh  count_steps {
341eb9441ebSdrh    SELECT t3.x, t1.a, coalesce(t2.a,9999)
342eb9441ebSdrh      FROM t3 JOIN
343eb9441ebSdrh           t1 LEFT JOIN t2 ON (t1.c+1=t2.c AND t1.d=t2.d) OR (t1.f||'x')=t2.f
344eb9441ebSdrh     WHERE t1.a=t3.y OR t1.b=t3.y*11 OR (t1.c=27027 AND round(t1.d)==80)
345eb9441ebSdrh    ORDER BY 1, 2
346eb9441ebSdrh  }
347eb9441ebSdrh} {1 80 9999 2 80 9999 scan 1 sort 1}
348eb9441ebSdrhdo_test where9-2.8 {
349eb9441ebSdrh  count_steps {
350eb9441ebSdrh    SELECT t3.x, t1.a, coalesce(t2.a,9999)
351eb9441ebSdrh      FROM t3 JOIN
352eb9441ebSdrh           t1 LEFT JOIN t2 ON (t1.c=t2.c AND t1.d=t2.d) OR (t1.f)=t2.f
353eb9441ebSdrh     WHERE t1.a=t3.y OR t1.b=t3.y*11 OR (t1.c=27027 AND round(t1.d)==80)
3541d46146bSdanielk1977    ORDER BY 1, 2, 3
355eb9441ebSdrh  }
356eb9441ebSdrh} {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}
35746129af9Sdrh
35846129af9Sdrh
35946129af9Sdrhifcapable explain {
360b3f0276bSdrh  do_eqp_test where9-3.1 {
36146129af9Sdrh    SELECT t2.a FROM t1, t2
36247eb16d4Sdan    WHERE t1.a=80 AND ((t1.c=t2.c AND t1.d=t2.d) OR t1.f=t2.f)
363b3f0276bSdrh  } [string map {"\n  " \n} {
364b3f0276bSdrh    QUERY PLAN
3658210233cSdrh    |--SEARCH t1 USING INTEGER PRIMARY KEY (rowid=?)
3665d72d924Sdrh    `--MULTI-INDEX OR
367bd462bccSdrh       |--INDEX 1
3688210233cSdrh       |  `--SEARCH t2 USING INDEX t2d (d=?)
369bd462bccSdrh       `--INDEX 3
3708210233cSdrh          `--SEARCH t2 USING COVERING INDEX t2f (f=?)
371b3f0276bSdrh  }]
372b3f0276bSdrh  do_eqp_test where9-3.2 {
37346129af9Sdrh    SELECT coalesce(t2.a,9999)
37446129af9Sdrh    FROM t1 LEFT JOIN t2 ON (t1.c+1=t2.c AND t1.d=t2.d) OR (t1.f||'x')=t2.f
37546129af9Sdrh    WHERE t1.a=80
376b3f0276bSdrh  } [string map {"\n  " \n} {
377b3f0276bSdrh    QUERY PLAN
3788210233cSdrh    |--SEARCH t1 USING INTEGER PRIMARY KEY (rowid=?)
3795d72d924Sdrh    `--MULTI-INDEX OR
380bd462bccSdrh       |--INDEX 1
381*c583719bSdrh       |  `--SEARCH t2 USING INDEX t2d (d=?) LEFT-JOIN
382bd462bccSdrh       `--INDEX 2
383*c583719bSdrh          `--SEARCH t2 USING COVERING INDEX t2f (f=?) LEFT-JOIN
384b3f0276bSdrh  }]
38546129af9Sdrh}
38646129af9Sdrh
38704bbcd5cSdrh# Make sure that INDEXED BY and multi-index OR clauses play well with
38804bbcd5cSdrh# one another.
38904bbcd5cSdrh#
39004bbcd5cSdrhdo_test where9-4.1 {
39104bbcd5cSdrh  count_steps {
39204bbcd5cSdrh    SELECT a FROM t1
39304bbcd5cSdrh     WHERE b>1000
39404bbcd5cSdrh       AND (c=31031 OR d IS NULL)
39504bbcd5cSdrh     ORDER BY +a
39604bbcd5cSdrh  }
39704bbcd5cSdrh} {92 93 97 scan 0 sort 1}
39804bbcd5cSdrhdo_test where9-4.2 {
39904bbcd5cSdrh  count_steps {
40004bbcd5cSdrh    SELECT a FROM t1
40104bbcd5cSdrh     WHERE b>1000
40204bbcd5cSdrh       AND (c=31031 OR +d IS NULL)
40304bbcd5cSdrh     ORDER BY +a
40404bbcd5cSdrh  }
40504bbcd5cSdrh} {92 93 97 scan 0 sort 1}
40604bbcd5cSdrhdo_test where9-4.3 {
40704bbcd5cSdrh  count_steps {
40804bbcd5cSdrh    SELECT a FROM t1
40904bbcd5cSdrh     WHERE +b>1000
41004bbcd5cSdrh       AND (c=31031 OR d IS NULL)
41104bbcd5cSdrh     ORDER BY +a
41204bbcd5cSdrh  }
41304bbcd5cSdrh} {92 93 97 scan 0 sort 1}
41404bbcd5cSdrhdo_test where9-4.4 {
41504bbcd5cSdrh  count_steps {
41604bbcd5cSdrh    SELECT a FROM t1 INDEXED BY t1b
41704bbcd5cSdrh     WHERE b>1000
41804bbcd5cSdrh       AND (c=31031 OR d IS NULL)
41904bbcd5cSdrh     ORDER BY +a
42004bbcd5cSdrh  }
42104bbcd5cSdrh} {92 93 97 scan 0 sort 1}
42204bbcd5cSdrhdo_test where9-4.5 {
42304bbcd5cSdrh  catchsql {
42404bbcd5cSdrh    SELECT a FROM t1 INDEXED BY t1b
42504bbcd5cSdrh     WHERE +b>1000
42604bbcd5cSdrh       AND (c=31031 OR d IS NULL)
42704bbcd5cSdrh     ORDER BY +a
42804bbcd5cSdrh  }
429094afffaSdrh} {0 {92 93 97}}
43004bbcd5cSdrhdo_test where9-4.6 {
43104bbcd5cSdrh  count_steps {
43204bbcd5cSdrh    SELECT a FROM t1 NOT INDEXED
43304bbcd5cSdrh     WHERE b>1000
43404bbcd5cSdrh       AND (c=31031 OR d IS NULL)
43504bbcd5cSdrh     ORDER BY +a
43604bbcd5cSdrh  }
43704bbcd5cSdrh} {92 93 97 scan 98 sort 1}
43804bbcd5cSdrhdo_test where9-4.7 {
43904bbcd5cSdrh  catchsql {
44004bbcd5cSdrh    SELECT a FROM t1 INDEXED BY t1c
44104bbcd5cSdrh     WHERE b>1000
44204bbcd5cSdrh       AND (c=31031 OR d IS NULL)
44304bbcd5cSdrh     ORDER BY +a
44404bbcd5cSdrh  }
445094afffaSdrh} {0 {92 93 97}}
44604bbcd5cSdrhdo_test where9-4.8 {
44704bbcd5cSdrh  catchsql {
44804bbcd5cSdrh    SELECT a FROM t1 INDEXED BY t1d
44904bbcd5cSdrh     WHERE b>1000
45004bbcd5cSdrh       AND (c=31031 OR d IS NULL)
45104bbcd5cSdrh     ORDER BY +a
45204bbcd5cSdrh  }
453094afffaSdrh} {0 {92 93 97}}
45404bbcd5cSdrh
45504bbcd5cSdrh# The (c=31031 OR d IS NULL) clause is preferred over b>1000 because
45604bbcd5cSdrh# the former is an equality test which is expected to return fewer rows.
45704bbcd5cSdrh#
458b3f0276bSdrhdo_eqp_test where9-5.1 {
459b3f0276bSdrh  SELECT a FROM t1 WHERE b>1000 AND (c=31031 OR d IS NULL)
46047eb16d4Sdan} {
461b3f0276bSdrh  QUERY PLAN
4625d72d924Sdrh  `--MULTI-INDEX OR
463bd462bccSdrh     |--INDEX 1
4648210233cSdrh     |  `--SEARCH t1 USING INDEX t1c (c=?)
465bd462bccSdrh     `--INDEX 2
4668210233cSdrh        `--SEARCH t1 USING INDEX t1d (d=?)
46747eb16d4Sdan}
46804bbcd5cSdrh
46904bbcd5cSdrh# In contrast, b=1000 is preferred over any OR-clause.
47004bbcd5cSdrh#
471b3f0276bSdrhdo_eqp_test where9-5.2 {
472b3f0276bSdrh  SELECT a FROM t1 WHERE b=1000 AND (c=31031 OR d IS NULL)
4738210233cSdrh} {SEARCH t1 USING INDEX t1b (b=?)}
47404bbcd5cSdrh
47504bbcd5cSdrh# Likewise, inequalities in an AND are preferred over inequalities in
47604bbcd5cSdrh# an OR.
47704bbcd5cSdrh#
478b3f0276bSdrhdo_eqp_test where9-5.3 {
479b3f0276bSdrh  SELECT a FROM t1 WHERE b>1000 AND (c>=31031 OR d IS NULL)
4808210233cSdrh} {SEARCH t1 USING INDEX t1b (b>?)}
48104bbcd5cSdrh
482171256c4Sdrh############################################################################
483171256c4Sdrh# Make sure OR-clauses work correctly on UPDATE and DELETE statements.
484171256c4Sdrh
485171256c4Sdrhdo_test where9-6.2.1 {
486171256c4Sdrh  db eval {SELECT count(*) FROM t1 UNION ALL SELECT a FROM t1 WHERE a>=85}
487171256c4Sdrh} {99 85 86 87 88 89 90 91 92 93 94 95 96 97 98 99}
488171256c4Sdrh
489171256c4Sdrhdo_test where9-6.2.2 {   ;# Deletes entries 90 91 92 96 97 99
490171256c4Sdrh  count_steps {
491171256c4Sdrh     BEGIN;
492171256c4Sdrh     DELETE FROM t1
493171256c4Sdrh     WHERE b IS NULL
494171256c4Sdrh        OR c IS NULL
495171256c4Sdrh        OR d IS NULL
496171256c4Sdrh  }
497171256c4Sdrh} {scan 0 sort 0}
498171256c4Sdrh
499171256c4Sdrhdo_test where9-6.2.3 {
500171256c4Sdrh  db eval {
501171256c4Sdrh    SELECT count(*) FROM t1 UNION ALL
502171256c4Sdrh    SELECT a FROM t1 WHERE a>=85;
503171256c4Sdrh    ROLLBACK;
504171256c4Sdrh  }
505171256c4Sdrh} {93 85 86 87 88 89 93 94 95 98}
506171256c4Sdrh
507171256c4Sdrhdo_test where9-6.2.4 {   ;# Deletes entries 90 91 92 96 97 99
508171256c4Sdrh  count_steps {
509171256c4Sdrh     BEGIN;
510171256c4Sdrh     DELETE FROM t1
511171256c4Sdrh     WHERE +b IS NULL
512171256c4Sdrh        OR c IS NULL
513171256c4Sdrh        OR d IS NULL
514171256c4Sdrh  }
515171256c4Sdrh} {scan 98 sort 0}
516171256c4Sdrh
517171256c4Sdrhdo_test where9-6.2.5 {
518171256c4Sdrh  db eval {
519171256c4Sdrh     SELECT count(*) FROM t1 UNION ALL
520171256c4Sdrh     SELECT a FROM t1 WHERE a>=85;
521171256c4Sdrh     ROLLBACK;
522171256c4Sdrh  }
523171256c4Sdrh} {93 85 86 87 88 89 93 94 95 98}
524171256c4Sdrh
525171256c4Sdrhdo_test where9-6.2.6 {
526171256c4Sdrh  count_steps {
527171256c4Sdrh     BEGIN;
528171256c4Sdrh     UPDATE t1 SET a=a+100
529171256c4Sdrh     WHERE (b IS NULL
530171256c4Sdrh            OR c IS NULL
531171256c4Sdrh            OR d IS NULL)
532171256c4Sdrh       AND a!=92
533171256c4Sdrh       AND a!=97
534171256c4Sdrh  }
535171256c4Sdrh} {scan 0 sort 0}   ;# Add 100 to entries 90 91 96 99
536171256c4Sdrh
537171256c4Sdrhdo_test where9-6.2.7 {
538171256c4Sdrh  db eval {
539171256c4Sdrh     SELECT count(*) FROM t1 UNION ALL
540171256c4Sdrh     SELECT a FROM t1 WHERE a>=85;
541171256c4Sdrh     ROLLBACK
542171256c4Sdrh  }
543171256c4Sdrh} {99 85 86 87 88 89 92 93 94 95 97 98 190 191 196 199}
544171256c4Sdrh
545171256c4Sdrhdo_test where9-6.2.8 {   ;# Deletes entries 90 91 92 97 99
546171256c4Sdrh  count_steps {
547171256c4Sdrh     BEGIN;
548171256c4Sdrh     DELETE FROM t1
549171256c4Sdrh     WHERE (b IS NULL
550171256c4Sdrh            OR c IS NULL
551171256c4Sdrh            OR d IS NULL)
552171256c4Sdrh       AND a!=96
553171256c4Sdrh  }
554171256c4Sdrh} {scan 0 sort 0}
555171256c4Sdrh
556171256c4Sdrhdo_test where9-6.2.9 {
557171256c4Sdrh  db eval {
558171256c4Sdrh     SELECT count(*) FROM t1 UNION ALL SELECT a FROM t1 WHERE a>=85;
559171256c4Sdrh     ROLLBACK;
560171256c4Sdrh  }
561171256c4Sdrh} {94 85 86 87 88 89 93 94 95 96 98}
562171256c4Sdrh
563171256c4Sdrhdo_test where9-6.3.1 {
564171256c4Sdrh  count_steps {
565171256c4Sdrh    BEGIN;
566171256c4Sdrh    DELETE FROM t1
567171256c4Sdrh     WHERE (b IS NULL AND c NOT NULL AND d NOT NULL)
568171256c4Sdrh        OR (b NOT NULL AND c IS NULL AND d NOT NULL)
569171256c4Sdrh        OR (b NOT NULL AND c NOT NULL AND d IS NULL)
570171256c4Sdrh  }
571171256c4Sdrh} {scan 0 sort 0}   ;# DELETEs rows 90 91 92 97
572171256c4Sdrhdo_test where9-6.3.2 {
573171256c4Sdrh  db eval {
574171256c4Sdrh    SELECT count(*) FROM t1 UNION ALL
575171256c4Sdrh    SELECT a FROM t1 WHERE a BETWEEN 85 AND 100;
576171256c4Sdrh    ROLLBACK;
577171256c4Sdrh  }
578171256c4Sdrh} {95 85 86 87 88 89 93 94 95 96 98 99}
579171256c4Sdrh
580171256c4Sdrhdo_test where9-6.3.3 {
581171256c4Sdrh  count_steps {
582171256c4Sdrh    BEGIN;
583171256c4Sdrh    UPDATE t1 SET a=a+100
584171256c4Sdrh     WHERE (b IS NULL AND c NOT NULL AND d NOT NULL)
585171256c4Sdrh        OR (b NOT NULL AND c IS NULL AND d NOT NULL)
586171256c4Sdrh        OR (b NOT NULL AND c NOT NULL AND d IS NULL)
587171256c4Sdrh  }
588171256c4Sdrh} {scan 0 sort 0}   ;# Add 100 to rowids 90 91 92 97
589171256c4Sdrhdo_test where9-6.3.4 {
590171256c4Sdrh  db eval {
591171256c4Sdrh    SELECT count(*) FROM t1 UNION ALL
592171256c4Sdrh    SELECT a FROM t1 WHERE a BETWEEN 85 AND 200;
593171256c4Sdrh    ROLLBACK;
594171256c4Sdrh  }
595171256c4Sdrh} {99 85 86 87 88 89 93 94 95 96 98 99 190 191 192 197}
596171256c4Sdrh
597171256c4Sdrhdo_test where9-6.3.5 {
598171256c4Sdrh  count_steps {
599171256c4Sdrh    BEGIN;
600171256c4Sdrh    DELETE FROM t1
601171256c4Sdrh     WHERE (+b IS NULL AND c NOT NULL AND d NOT NULL)
602171256c4Sdrh        OR (b NOT NULL AND c IS NULL AND d NOT NULL)
603171256c4Sdrh        OR (b NOT NULL AND c NOT NULL AND d IS NULL)
604171256c4Sdrh  }
60574f91d44Sdrh} {scan 98 sort 0}   ;# DELETEs rows 90 91 92 97
606171256c4Sdrhdo_test where9-6.3.6 {
607171256c4Sdrh  db eval {
608171256c4Sdrh    SELECT count(*) FROM t1 UNION ALL
609171256c4Sdrh    SELECT a FROM t1 WHERE a BETWEEN 85 AND 100;
610171256c4Sdrh    ROLLBACK;
611171256c4Sdrh  }
612171256c4Sdrh} {95 85 86 87 88 89 93 94 95 96 98 99}
613171256c4Sdrh
614171256c4Sdrhdo_test where9-6.3.7 {
615171256c4Sdrh  count_steps {
616171256c4Sdrh    BEGIN;
617171256c4Sdrh    UPDATE t1 SET a=a+100
618171256c4Sdrh     WHERE (b IS NULL AND c NOT NULL AND d NOT NULL)
619171256c4Sdrh        OR (b NOT NULL AND +c IS NULL AND d NOT NULL)
620171256c4Sdrh        OR (b NOT NULL AND c NOT NULL AND d IS NULL)
621171256c4Sdrh  }
62274f91d44Sdrh} {scan 98 sort 0}   ;# Add 100 to rowids 90 91 92 97
623171256c4Sdrhdo_test where9-6.3.8 {
624171256c4Sdrh  db eval {
625171256c4Sdrh    SELECT count(*) FROM t1 UNION ALL
626171256c4Sdrh    SELECT a FROM t1 WHERE a BETWEEN 85 AND 100;
627171256c4Sdrh    ROLLBACK;
628171256c4Sdrh  }
629171256c4Sdrh} {99 85 86 87 88 89 93 94 95 96 98 99}
630171256c4Sdrh
631171256c4Sdrh
632171256c4Sdrhdo_test where9-6.4.1 {
633171256c4Sdrh  count_steps {
634171256c4Sdrh    BEGIN;
635171256c4Sdrh    DELETE FROM t1
636171256c4Sdrh     WHERE (b>=950 AND b<=1010) OR (b IS NULL AND c NOT NULL)
637171256c4Sdrh  }
638171256c4Sdrh} {scan 0 sort 0}  ;# DELETE rows 87 88 89 90 91
639171256c4Sdrhdo_test where9-6.4.2 {
640171256c4Sdrh  db eval {
641171256c4Sdrh    SELECT count(*) FROM t1 UNION ALL
642171256c4Sdrh    SELECT a FROM t1 WHERE a BETWEEN 85 AND 100;
643171256c4Sdrh    ROLLBACK;
644171256c4Sdrh  }
645171256c4Sdrh} {94 85 86 92 93 94 95 96 97 98 99}
646171256c4Sdrhdo_test where9-6.4.3 {
647171256c4Sdrh  count_steps {
648171256c4Sdrh    BEGIN;
649171256c4Sdrh    UPDATE t1 SET a=a+100
650171256c4Sdrh     WHERE (b>=950 AND b<=1010) OR (b IS NULL AND c NOT NULL)
651171256c4Sdrh  }
652171256c4Sdrh} {scan 0 sort 0}  ;# Add 100 to rowids 87 88 89 90 91
653171256c4Sdrhdo_test where9-6.4.4 {
654171256c4Sdrh  db eval {
655171256c4Sdrh    SELECT count(*) FROM t1 UNION ALL
656171256c4Sdrh    SELECT a FROM t1 WHERE a BETWEEN 85 AND 100;
657171256c4Sdrh    ROLLBACK;
658171256c4Sdrh  }
659171256c4Sdrh} {99 85 86 92 93 94 95 96 97 98 99}
660171256c4Sdrh
661171256c4Sdrh
662171256c4Sdrhdo_test where9-6.5.1 {
663171256c4Sdrh  count_steps {
664171256c4Sdrh    BEGIN;
665171256c4Sdrh    DELETE FROM t1
666171256c4Sdrh     WHERE a=83
667171256c4Sdrh        OR b=913
668171256c4Sdrh        OR c=28028
669171256c4Sdrh        OR (d>=82 AND d<83)
670171256c4Sdrh        OR (e>2802 AND e<2803)
671171256c4Sdrh        OR f='fghijklmn'
672171256c4Sdrh        OR g='hgfedcb'
673171256c4Sdrh  }
674171256c4Sdrh} {scan 0 sort 0}   ;#  DELETE rows 5 31 57 82 83 84 85 86 87
675171256c4Sdrhdo_test where9-6.5.2 {
676171256c4Sdrh  db eval {
677171256c4Sdrh    SELECT count(*) FROM t1 UNION ALL
678171256c4Sdrh    SELECT a FROM t1 WHERE a IN (5,31,57,82,83,84,85,86,87);
679171256c4Sdrh    ROLLBACK;
680171256c4Sdrh  }
681171256c4Sdrh} {90}
682171256c4Sdrh
683171256c4Sdrhdo_test where9-6.5.3 {
684171256c4Sdrh  count_steps {
685171256c4Sdrh    BEGIN;
686171256c4Sdrh    UPDATE t1 SET a=a+100
687171256c4Sdrh     WHERE a=83
688171256c4Sdrh        OR b=913
689171256c4Sdrh        OR c=28028
690171256c4Sdrh        OR (d>=82 AND d<83)
691171256c4Sdrh        OR (e>2802 AND e<2803)
692171256c4Sdrh        OR f='fghijklmn'
693171256c4Sdrh        OR g='hgfedcb'
694171256c4Sdrh  }
695171256c4Sdrh} {scan 0 sort 0}   ;#  Add 100 to rowids 5 31 57 82 83 84 85 86 87
696171256c4Sdrhdo_test where9-6.5.4 {
697171256c4Sdrh  db eval {
698171256c4Sdrh    SELECT count(*) FROM t1 UNION ALL
6993f4d1d1bSdrh    SELECT a FROM t1 WHERE a%100 IN (5,31,57,82,83,84,85,86,87) ORDER BY rowid;
700171256c4Sdrh    ROLLBACK;
701171256c4Sdrh  }
702171256c4Sdrh} {99 105 131 157 182 183 184 185 186 187}
703171256c4Sdrh
704103bd88cSdrhdo_test where9-6.6.1 {
705103bd88cSdrh  count_steps {
706103bd88cSdrh    BEGIN;
707103bd88cSdrh    DELETE FROM t1
708103bd88cSdrh     WHERE (b IS NULL AND c NOT NULL AND d NOT NULL)
709103bd88cSdrh        OR (b NOT NULL AND +c IS NULL AND d NOT NULL)
710103bd88cSdrh        OR (b NOT NULL AND c NOT NULL AND d IS NULL)
711103bd88cSdrh  }
71274f91d44Sdrh} {scan 98 sort 0}   ;# DELETEs rows 90 91 92 97
713103bd88cSdrhdo_test where9-6.6.2 {
714103bd88cSdrh  db eval {
715103bd88cSdrh    SELECT count(*) FROM t1 UNION ALL
716103bd88cSdrh    SELECT a FROM t1 WHERE a BETWEEN 85 AND 100;
717103bd88cSdrh    ROLLBACK;
718103bd88cSdrh  }
719103bd88cSdrh} {95 85 86 87 88 89 93 94 95 96 98 99}
720103bd88cSdrh
721103bd88cSdrhdo_test where9-6.6.3 {
722103bd88cSdrh  count_steps {
723103bd88cSdrh    BEGIN;
724103bd88cSdrh    UPDATE t1 SET a=a+100
725103bd88cSdrh     WHERE (b IS NULL AND c NOT NULL AND d NOT NULL)
726103bd88cSdrh        OR (b NOT NULL AND +c IS NULL AND d NOT NULL)
727103bd88cSdrh        OR (b NOT NULL AND c NOT NULL AND d IS NULL)
728103bd88cSdrh  }
72974f91d44Sdrh} {scan 98 sort 0}   ;# Add 100 to rowids 90 91 92 97
730103bd88cSdrhdo_test where9-6.6.4 {
731103bd88cSdrh  db eval {
732103bd88cSdrh    SELECT count(*) FROM t1 UNION ALL
733103bd88cSdrh    SELECT a FROM t1 WHERE a BETWEEN 85 AND 200;
734103bd88cSdrh    ROLLBACK;
735103bd88cSdrh  }
736103bd88cSdrh} {99 85 86 87 88 89 93 94 95 96 98 99 190 191 192 197}
737103bd88cSdrh
738103bd88cSdrhdo_test where9-6.7.1 {
739103bd88cSdrh  count_steps {
740103bd88cSdrh    BEGIN;
741103bd88cSdrh    DELETE FROM t1 NOT INDEXED
742103bd88cSdrh     WHERE (b IS NULL AND c NOT NULL AND d NOT NULL)
743103bd88cSdrh        OR (b NOT NULL AND c IS NULL AND d NOT NULL)
744103bd88cSdrh        OR (b NOT NULL AND c NOT NULL AND d IS NULL)
745103bd88cSdrh  }
746103bd88cSdrh} {scan 98 sort 0}   ;# DELETEs rows 90 91 92 97
747103bd88cSdrhdo_test where9-6.7.2 {
748103bd88cSdrh  db eval {
749103bd88cSdrh    SELECT count(*) FROM t1 UNION ALL
750103bd88cSdrh    SELECT a FROM t1 WHERE a BETWEEN 85 AND 100;
751103bd88cSdrh    ROLLBACK;
752103bd88cSdrh  }
753103bd88cSdrh} {95 85 86 87 88 89 93 94 95 96 98 99}
754103bd88cSdrh
755103bd88cSdrhdo_test where9-6.7.3 {
756103bd88cSdrh  count_steps {
757103bd88cSdrh    BEGIN;
758103bd88cSdrh    UPDATE t1 NOT INDEXED SET a=a+100
759103bd88cSdrh     WHERE (b IS NULL AND c NOT NULL AND d NOT NULL)
760103bd88cSdrh        OR (b NOT NULL AND c IS NULL AND d NOT NULL)
761103bd88cSdrh        OR (b NOT NULL AND c NOT NULL AND d IS NULL)
762103bd88cSdrh  }
763103bd88cSdrh} {scan 98 sort 0}   ;# Add 100 to rowids 90 91 92 97
764103bd88cSdrhdo_test where9-6.7.4 {
765103bd88cSdrh  db eval {
766103bd88cSdrh    SELECT count(*) FROM t1 UNION ALL
767103bd88cSdrh    SELECT a FROM t1 WHERE a BETWEEN 85 AND 200;
768103bd88cSdrh    ROLLBACK;
769103bd88cSdrh  }
770103bd88cSdrh} {99 85 86 87 88 89 93 94 95 96 98 99 190 191 192 197}
771103bd88cSdrh
772103bd88cSdrhdo_test where9-6.8.1 {
773103bd88cSdrh  catchsql {
774103bd88cSdrh    DELETE FROM t1 INDEXED BY t1b
775fd5874d2Sdrh     WHERE (+b IS NULL AND c NOT NULL AND d NOT NULL)
776103bd88cSdrh        OR (b NOT NULL AND c IS NULL AND d NOT NULL)
777103bd88cSdrh        OR (b NOT NULL AND c NOT NULL AND d IS NULL)
778103bd88cSdrh  }
779094afffaSdrh} {0 {}}
780103bd88cSdrhdo_test where9-6.8.2 {
781103bd88cSdrh  catchsql {
782103bd88cSdrh    UPDATE t1 INDEXED BY t1b SET a=a+100
783fd5874d2Sdrh     WHERE (+b IS NULL AND c NOT NULL AND d NOT NULL)
784fd5874d2Sdrh        OR (b NOT NULL AND c IS NULL AND d NOT NULL)
785fd5874d2Sdrh        OR (b NOT NULL AND c NOT NULL AND d IS NULL)
786fd5874d2Sdrh  }
787094afffaSdrh} {0 {}}
788299b2468Sdan
789299b2468Sdanset solution_possible 0
790175b8f06Sdrhifcapable stat4 {
791299b2468Sdan  if {[permutation] != "no_optimization"} { set solution_possible 1 }
792299b2468Sdan}
793299b2468Sdanif $solution_possible {
79474f91d44Sdrh  # When STAT3 is enabled, the "b NOT NULL" terms get translated
79574f91d44Sdrh  # into b>NULL, which can be satified by the index t1b.  It is a very
79674f91d44Sdrh  # expensive way to do the query, but it works, and so a solution is possible.
797f52bb8d3Sdan  do_test where9-6.8.3-stat4 {
798fd5874d2Sdrh    catchsql {
799fd5874d2Sdrh      UPDATE t1 INDEXED BY t1b SET a=a+100
800103bd88cSdrh       WHERE (b IS NULL AND c NOT NULL AND d NOT NULL)
801103bd88cSdrh          OR (b NOT NULL AND c IS NULL AND d NOT NULL)
802103bd88cSdrh          OR (b NOT NULL AND c NOT NULL AND d IS NULL)
803103bd88cSdrh    }
804fd5874d2Sdrh  } {0 {}}
805f52bb8d3Sdan  do_test where9-6.8.4-stat4 {
806fd5874d2Sdrh    catchsql {
807fd5874d2Sdrh      DELETE FROM t1 INDEXED BY t1b
808fd5874d2Sdrh       WHERE (b IS NULL AND c NOT NULL AND d NOT NULL)
809fd5874d2Sdrh          OR (b NOT NULL AND c IS NULL AND d NOT NULL)
810fd5874d2Sdrh          OR (b NOT NULL AND c NOT NULL AND d IS NULL)
811fd5874d2Sdrh    }
812fd5874d2Sdrh  } {0 {}}
81374f91d44Sdrh} else {
81474f91d44Sdrh  do_test where9-6.8.3 {
81574f91d44Sdrh    catchsql {
81674f91d44Sdrh      UPDATE t1 INDEXED BY t1b SET a=a+100
81774f91d44Sdrh       WHERE (b IS NULL AND c NOT NULL AND d NOT NULL)
81874f91d44Sdrh          OR (b NOT NULL AND c IS NULL AND d NOT NULL)
81974f91d44Sdrh          OR (b NOT NULL AND c NOT NULL AND d IS NULL)
82074f91d44Sdrh    }
821094afffaSdrh  } {0 {}}
82274f91d44Sdrh  do_test where9-6.8.4 {
82374f91d44Sdrh    catchsql {
82474f91d44Sdrh      DELETE FROM t1 INDEXED BY t1b
82574f91d44Sdrh       WHERE (b IS NULL AND c NOT NULL AND d NOT NULL)
82674f91d44Sdrh          OR (b NOT NULL AND c IS NULL AND d NOT NULL)
82774f91d44Sdrh          OR (b NOT NULL AND c NOT NULL AND d IS NULL)
82874f91d44Sdrh    }
829094afffaSdrh  } {0 {}}
83074f91d44Sdrh}
83185ae206eSdrh############################################################################
83285ae206eSdrh# Test cases where terms inside an OR series are combined with AND terms
83385ae206eSdrh# external to the OR clause.  In other words, cases where
83485ae206eSdrh#
83585ae206eSdrh#              x AND (y OR z)
83685ae206eSdrh#
83785ae206eSdrh# is able to use indices on x,y and x,z, or indices y,x and z,x.
83885ae206eSdrh#
83985ae206eSdrhdo_test where9-7.0 {
84085ae206eSdrh  execsql {
84185ae206eSdrh    CREATE TABLE t5(a, b, c, d, e, f, g, x, y);
84285ae206eSdrh    INSERT INTO t5
84385ae206eSdrh     SELECT a, b, c, e, d, f, g,
84485ae206eSdrh            CASE WHEN (a&1)!=0 THEN 'y' ELSE 'n' END,
84585ae206eSdrh            CASE WHEN (a&2)!=0 THEN 'y' ELSE 'n' END
84685ae206eSdrh       FROM t1;
84785ae206eSdrh    CREATE INDEX t5xb ON t5(x, b);
84885ae206eSdrh    CREATE INDEX t5xc ON t5(x, c);
84985ae206eSdrh    CREATE INDEX t5xd ON t5(x, d);
85085ae206eSdrh    CREATE INDEX t5xe ON t5(x, e);
85185ae206eSdrh    CREATE INDEX t5xf ON t5(x, f);
85285ae206eSdrh    CREATE INDEX t5xg ON t5(x, g);
85385ae206eSdrh    CREATE INDEX t5yb ON t5(y, b);
85485ae206eSdrh    CREATE INDEX t5yc ON t5(y, c);
85585ae206eSdrh    CREATE INDEX t5yd ON t5(y, d);
85685ae206eSdrh    CREATE INDEX t5ye ON t5(y, e);
85785ae206eSdrh    CREATE INDEX t5yf ON t5(y, f);
85885ae206eSdrh    CREATE INDEX t5yg ON t5(y, g);
85985ae206eSdrh    CREATE TABLE t6(a, b, c, e, d, f, g, x, y);
86085ae206eSdrh    INSERT INTO t6 SELECT * FROM t5;
86185ae206eSdrh    ANALYZE t5;
86285ae206eSdrh  }
86385ae206eSdrh} {}
86485ae206eSdrhdo_test where9-7.1.1 {
86585ae206eSdrh  count_steps {
86685ae206eSdrh    SELECT a FROM t5 WHERE x='y' AND (b=913 OR c=27027) ORDER BY a;
86785ae206eSdrh  }
86885ae206eSdrh} {79 81 83 scan 0 sort 1}
86985ae206eSdrhdo_test where9-7.1.2 {
87085ae206eSdrh  execsql {
87185ae206eSdrh    SELECT a FROM t6 WHERE x='y' AND (b=913 OR c=27027) ORDER BY a;
87285ae206eSdrh  }
87385ae206eSdrh} {79 81 83}
87485ae206eSdrhdo_test where9-7.1.3 {
87585ae206eSdrh  count_steps {
87685ae206eSdrh    SELECT a FROM t5 WHERE x='n' AND (b=913 OR c=27027) ORDER BY a;
87785ae206eSdrh  }
87885ae206eSdrh} {80 scan 0 sort 1}
87985ae206eSdrhdo_test where9-7.1.4 {
88085ae206eSdrh  execsql {
88185ae206eSdrh    SELECT a FROM t6 WHERE x='n' AND (b=913 OR c=27027) ORDER BY a;
88285ae206eSdrh  }
88385ae206eSdrh} {80}
88485ae206eSdrhdo_test where9-7.2.1 {
88585ae206eSdrh  count_steps {
88685ae206eSdrh    SELECT a FROM t5 WHERE (x='y' OR y='y') AND b=913 ORDER BY a;
88785ae206eSdrh  }
88885ae206eSdrh} {83 scan 0 sort 1}
88985ae206eSdrhdo_test where9-7.2.2 {
89085ae206eSdrh  execsql {
89185ae206eSdrh    SELECT a FROM t6 WHERE (x='y' OR y='y') AND b=913 ORDER BY a;
89285ae206eSdrh  }
89385ae206eSdrh} {83}
89485ae206eSdrhdo_test where9-7.3.1 {
89585ae206eSdrh  count_steps {
89685ae206eSdrh    SELECT a FROM t5 WHERE (x='y' OR y='y') AND c=27027 ORDER BY a;
89785ae206eSdrh  }
89885ae206eSdrh} {79 81 scan 0 sort 1}
89985ae206eSdrhdo_test where9-7.3.2 {
90085ae206eSdrh  execsql {
90185ae206eSdrh    SELECT a FROM t6 WHERE (x='y' OR y='y') AND c=27027 ORDER BY a;
90285ae206eSdrh  }
90385ae206eSdrh} {79 81}
90485ae206eSdrh
905331b67c1Sdrh# Fix for ticket [b7c8682cc17f32903f03a610bd0d35ffd3c1e6e4]
906331b67c1Sdrh# "Incorrect result from LEFT JOIN with OR in the WHERE clause"
907331b67c1Sdrh#
908331b67c1Sdrhdo_test where9-8.1 {
909331b67c1Sdrh  db eval {
910331b67c1Sdrh    CREATE TABLE t81(a INTEGER PRIMARY KEY, b, c, d);
911331b67c1Sdrh    CREATE TABLE t82(x INTEGER PRIMARY KEY, y);
912331b67c1Sdrh    CREATE TABLE t83(p INTEGER PRIMARY KEY, q);
913331b67c1Sdrh
914331b67c1Sdrh    INSERT INTO t81 VALUES(2,3,4,5);
915331b67c1Sdrh    INSERT INTO t81 VALUES(3,4,5,6);
916331b67c1Sdrh    INSERT INTO t82 VALUES(2,4);
917331b67c1Sdrh    INSERT INTO t83 VALUES(5,55);
918331b67c1Sdrh
919331b67c1Sdrh    SELECT *
920331b67c1Sdrh      FROM t81 LEFT JOIN t82 ON y=b JOIN t83
921331b67c1Sdrh     WHERE c==p OR d==p
922331b67c1Sdrh     ORDER BY +a;
923331b67c1Sdrh  }
924331b67c1Sdrh} {2 3 4 5 {} {} 5 55 3 4 5 6 2 4 5 55}
925832ee3d4Sdrhdo_test where9-8.2 {
926832ee3d4Sdrh  db eval {
927832ee3d4Sdrh    SELECT *
928832ee3d4Sdrh      FROM t81 LEFT JOIN (t82) ON y=b JOIN t83
929832ee3d4Sdrh     WHERE c==p OR d==p
930832ee3d4Sdrh     ORDER BY +a;
931832ee3d4Sdrh  }
932832ee3d4Sdrh} {2 3 4 5 {} {} 5 55 3 4 5 6 2 4 5 55}
933832ee3d4Sdrhdo_test where9-8.3 {
934832ee3d4Sdrh  db eval {
935832ee3d4Sdrh    SELECT *
936832ee3d4Sdrh      FROM (t81) LEFT JOIN (main.t82) ON y=b JOIN t83
937832ee3d4Sdrh     WHERE c==p OR d==p
938832ee3d4Sdrh     ORDER BY +a;
939832ee3d4Sdrh  }
940832ee3d4Sdrh} {2 3 4 5 {} {} 5 55 3 4 5 6 2 4 5 55}
94185ae206eSdrh
942b3129fa5Sdrh# Fix for ticket [f2369304e47167e3e644e2f1fe9736063391d7b7]
943b3129fa5Sdrh# Incorrect results when OR is used in the ON clause of a LEFT JOIN
944b3129fa5Sdrh#
945b3129fa5Sdrhdo_test where9-9.1 {
946b3129fa5Sdrh  db eval {
947b3129fa5Sdrh    CREATE TABLE t91(x); INSERT INTO t91 VALUES(1);
948b3129fa5Sdrh    CREATE TABLE t92(y INTEGER PRIMARY KEY,a,b);
949b3129fa5Sdrh    INSERT INTO t92 VALUES(1,2,3);
950b3129fa5Sdrh    SELECT 1 FROM t91 LEFT JOIN t92 ON a=2 OR b=3;
951b3129fa5Sdrh    SELECT 2 FROM t91 LEFT JOIN t92 ON a=2 AND b=3;
952b3129fa5Sdrh    SELECT 3 FROM t91 LEFT JOIN t92 ON (a=2 OR b=3) AND y IS NULL;
953b3129fa5Sdrh    SELECT 4 FROM t91 LEFT JOIN t92 ON (a=2 AND b=3) AND y IS NULL;
954b3129fa5Sdrh    CREATE TEMP TABLE x9 AS SELECT * FROM t91 LEFT JOIN t92 ON a=2 OR b=3;
955b3129fa5Sdrh    SELECT 5 FROM x9 WHERE y IS NULL;
956b3129fa5Sdrh    SELECT 6 FROM t91 LEFT JOIN t92 ON a=2 OR b=3 WHERE y IS NULL;
957b3129fa5Sdrh    SELECT 7 FROM t91 LEFT JOIN t92 ON a=2 AND b=3 WHERE y IS NULL;
958b3129fa5Sdrh    SELECT 8 FROM t91 LEFT JOIN t92 ON a=22 OR b=33 WHERE y IS NULL;
959b3129fa5Sdrh    SELECT 9 FROM t91 LEFT JOIN t92 ON a=22 AND b=33 WHERE y IS NULL;
960b3129fa5Sdrh  }
961b3129fa5Sdrh} {1 2 3 4 8 9}
962b3129fa5Sdrh
963d41d39f2Sdrh# Fix for ticket [bc878246eafe0f52c519e29049b2fe4a99491b27]
964d41d39f2Sdrh# Incorrect result when OR is used in a join to the right of a LEFT JOIN
965d41d39f2Sdrh#
966d41d39f2Sdrhdo_test where9-10.1 {
967d41d39f2Sdrh  db eval {
968d41d39f2Sdrh    CREATE TABLE t101 (id INTEGER PRIMARY KEY);
969d41d39f2Sdrh    INSERT INTO t101 VALUES (1);
970d41d39f2Sdrh    SELECT * FROM t101 AS t0
971d41d39f2Sdrh         LEFT JOIN t101 AS t1 ON t1.id BETWEEN 10 AND 20
972d41d39f2Sdrh         JOIN t101 AS t2 ON (t2.id = t0.id OR (t2.id<>555 AND t2.id=t1.id));
973d41d39f2Sdrh  }
974d41d39f2Sdrh} {1 {} 1}
975d41d39f2Sdrhdo_test where9-10.2 {
976d41d39f2Sdrh  db eval {
977d41d39f2Sdrh    CREATE TABLE t102 (id TEXT UNIQUE NOT NULL);
978d41d39f2Sdrh    INSERT INTO t102 VALUES ('1');
979d41d39f2Sdrh    SELECT * FROM t102 AS t0
980d41d39f2Sdrh         LEFT JOIN t102 AS t1 ON t1.id GLOB 'abc%'
981d41d39f2Sdrh         JOIN t102 AS t2 ON (t2.id = t0.id OR (t2.id<>555 AND t2.id=t1.id));
982d41d39f2Sdrh  }
983d41d39f2Sdrh} {1 {} 1}
984d41d39f2Sdrh
98593ffb50fSdrh# dbsqlfuzz 9df1d53c24c4c96af0dae15ee764897af415ac76
98693ffb50fSdrh# The MULTI-INDEX OR processing evaluates the same WHERE-clause sub-expression
98793ffb50fSdrh# twice.  But if that sub-expression contains a UNION ALL SELECT statement
98893ffb50fSdrh# subject to query flattening, the sub-expression might be transformed in a
98993ffb50fSdrh# way that it can only be code-generated once.  An assert() will fail on
99093ffb50fSdrh# the second attempt to generate code from the same sub-expression.
99193ffb50fSdrh# The solution is to make a copy of sub-expressions used by MULTI-INDEX OR
99293ffb50fSdrh#
99393ffb50fSdrhreset_db
99493ffb50fSdrhdo_execsql_test where9-11.1 {
99593ffb50fSdrh  CREATE TABLE t1(a INTEGER PRIMARY KEY, b TEXT);
99693ffb50fSdrh  CREATE TABLE t2_a(k INTEGER PRIMARY KEY, v TEXT);
99793ffb50fSdrh  CREATE TABLE t2_b(k INTEGER PRIMARY KEY, v TEXT);
99893ffb50fSdrh  CREATE VIEW t2 AS SELECT * FROM t2_a UNION ALL SELECT * FROM t2_b;
99993ffb50fSdrh  SELECT 1 FROM t1 JOIN t1 USING(a)
100093ffb50fSdrh   WHERE (a=1)
100193ffb50fSdrh      OR (a=2 AND (SELECT 4 FROM t2,(SELECT 5 FROM t1 ORDER BY a) WHERE a));
100293ffb50fSdrh} {}
1003d41d39f2Sdrh
100446129af9Sdrhfinish_test
1005