xref: /sqlite-3.40.0/test/skipscan1.test (revision 8210233c)
1c2b23e7aSdrh# 2013-11-13
2c2b23e7aSdrh#
3c2b23e7aSdrh# The author disclaims copyright to this source code.  In place of
4c2b23e7aSdrh# a legal notice, here is a blessing:
5c2b23e7aSdrh#
6c2b23e7aSdrh#    May you do good and not evil.
7c2b23e7aSdrh#    May you find forgiveness for yourself and forgive others.
8c2b23e7aSdrh#    May you share freely, never taking more than you give.
9c2b23e7aSdrh#
10c2b23e7aSdrh#***********************************************************************
11c2b23e7aSdrh#
12c2b23e7aSdrh# This file implements tests of the "skip-scan" query strategy.
13c2b23e7aSdrh#
14c2b23e7aSdrh
15c2b23e7aSdrhset testdir [file dirname $argv0]
16c2b23e7aSdrhsource $testdir/tester.tcl
17c2b23e7aSdrh
18c2b23e7aSdrhdo_execsql_test skipscan1-1.1 {
19c2b23e7aSdrh  CREATE TABLE t1(a TEXT, b INT, c INT, d INT);
20c2b23e7aSdrh  CREATE INDEX t1abc ON t1(a,b,c);
21c2b23e7aSdrh  INSERT INTO t1 VALUES('abc',123,4,5);
22c2b23e7aSdrh  INSERT INTO t1 VALUES('abc',234,5,6);
23c2b23e7aSdrh  INSERT INTO t1 VALUES('abc',234,6,7);
24c2b23e7aSdrh  INSERT INTO t1 VALUES('abc',345,7,8);
25c2b23e7aSdrh  INSERT INTO t1 VALUES('def',567,8,9);
26c2b23e7aSdrh  INSERT INTO t1 VALUES('def',345,9,10);
27c2b23e7aSdrh  INSERT INTO t1 VALUES('bcd',100,6,11);
28c2b23e7aSdrh
29c2b23e7aSdrh  /* Fake the sqlite_stat1 table so that the query planner believes
30c2b23e7aSdrh  ** the table contains thousands of rows and that the first few
31c2b23e7aSdrh  ** columns are not selective. */
32c2b23e7aSdrh  ANALYZE;
33c2b23e7aSdrh  DELETE FROM sqlite_stat1;
34c2b23e7aSdrh  INSERT INTO sqlite_stat1 VALUES('t1','t1abc','10000 5000 2000 10');
35c2b23e7aSdrh  ANALYZE sqlite_master;
36c2b23e7aSdrh} {}
37c2b23e7aSdrh
38c2b23e7aSdrh# Simple queries that leave the first one or two columns of the
39c2b23e7aSdrh# index unconstrainted.
40c2b23e7aSdrh#
41c2b23e7aSdrhdo_execsql_test skipscan1-1.2 {
42c2b23e7aSdrh  SELECT a,b,c,d,'|' FROM t1 WHERE b=345 ORDER BY a;
43c2b23e7aSdrh} {abc 345 7 8 | def 345 9 10 |}
44c2b23e7aSdrhdo_execsql_test skipscan1-1.2eqp {
45c2b23e7aSdrh  EXPLAIN QUERY PLAN
4699bbcc82Sdrh  SELECT a,b,c,d,'|' FROM t1 WHERE d<>99 AND b=345 ORDER BY a;
47c2b23e7aSdrh} {/* USING INDEX t1abc (ANY(a) AND b=?)*/}
48c2b23e7aSdrhdo_execsql_test skipscan1-1.2sort {
49c2b23e7aSdrh  EXPLAIN QUERY PLAN
5099bbcc82Sdrh  SELECT a,b,c,d,'|' FROM t1 WHERE d<>99 AND b=345 ORDER BY a;
51c2b23e7aSdrh} {~/*ORDER BY*/}
52c2b23e7aSdrh
53c2b23e7aSdrhdo_execsql_test skipscan1-1.3 {
5499bbcc82Sdrh  SELECT a,b,c,d,'|' FROM t1 WHERE d<>99 AND b=345 ORDER BY a DESC;
55c2b23e7aSdrh} {def 345 9 10 | abc 345 7 8 |}
56c2b23e7aSdrhdo_execsql_test skipscan1-1.3eqp {
57c2b23e7aSdrh  EXPLAIN QUERY PLAN
5899bbcc82Sdrh  SELECT a,b,c,d,'|' FROM t1 WHERE d<>99 AND b=345 ORDER BY a DESC;
59c2b23e7aSdrh} {/* USING INDEX t1abc (ANY(a) AND b=?)*/}
60c2b23e7aSdrhdo_execsql_test skipscan1-1.3sort {
61c2b23e7aSdrh  EXPLAIN QUERY PLAN
6299bbcc82Sdrh  SELECT a,b,c,d,'|' FROM t1 WHERE d<>99 AND b=345 ORDER BY a DESC;
63c2b23e7aSdrh} {~/*ORDER BY*/}
64c2b23e7aSdrh
65c2b23e7aSdrhdo_execsql_test skipscan1-1.4 {
66c2b23e7aSdrh  SELECT a,b,c,d,'|' FROM t1 WHERE c=6 ORDER BY a, b, c;
67c2b23e7aSdrh} {abc 234 6 7 | bcd 100 6 11 |}
68c2b23e7aSdrhdo_execsql_test skipscan1-1.4eqp {
69c2b23e7aSdrh  EXPLAIN QUERY PLAN
70c2b23e7aSdrh  SELECT a,b,c,d,'|' FROM t1 WHERE c=6 ORDER BY a, b, c;
71c2b23e7aSdrh} {/* USING INDEX t1abc (ANY(a) AND ANY(b) AND c=?)*/}
72c2b23e7aSdrhdo_execsql_test skipscan1-1.4sort {
73c2b23e7aSdrh  EXPLAIN QUERY PLAN
74c2b23e7aSdrh  SELECT a,b,c,d,'|' FROM t1 WHERE c=6 ORDER BY a, b, c;
75c2b23e7aSdrh} {~/*ORDER BY*/}
76c2b23e7aSdrh
772e5ef4edSdrhdo_execsql_test skipscan1-1.5 {
782e5ef4edSdrh  SELECT a,b,c,d,'|' FROM t1 WHERE c IN (6,7) ORDER BY a, b, c;
792e5ef4edSdrh} {abc 234 6 7 | abc 345 7 8 | bcd 100 6 11 |}
802e5ef4edSdrhdo_execsql_test skipscan1-1.5eqp {
812e5ef4edSdrh  EXPLAIN QUERY PLAN
822e5ef4edSdrh  SELECT a,b,c,d,'|' FROM t1 WHERE c IN (6,7) ORDER BY a, b, c;
832e5ef4edSdrh} {/* USING INDEX t1abc (ANY(a) AND ANY(b) AND c=?)*/}
842e5ef4edSdrhdo_execsql_test skipscan1-1.5sort {
852e5ef4edSdrh  EXPLAIN QUERY PLAN
862e5ef4edSdrh  SELECT a,b,c,d,'|' FROM t1 WHERE c IN (6,7) ORDER BY a, b, c;
872e5ef4edSdrh} {~/*ORDER BY*/}
882e5ef4edSdrh
892e5ef4edSdrhdo_execsql_test skipscan1-1.6 {
902e5ef4edSdrh  SELECT a,b,c,d,'|' FROM t1 WHERE c BETWEEN 6 AND 7 ORDER BY a, b, c;
912e5ef4edSdrh} {abc 234 6 7 | abc 345 7 8 | bcd 100 6 11 |}
922e5ef4edSdrhdo_execsql_test skipscan1-1.6eqp {
932e5ef4edSdrh  EXPLAIN QUERY PLAN
942e5ef4edSdrh  SELECT a,b,c,d,'|' FROM t1 WHERE c BETWEEN 6 AND 7 ORDER BY a, b, c;
952e5ef4edSdrh} {/* USING INDEX t1abc (ANY(a) AND ANY(b) AND c>? AND c<?)*/}
962e5ef4edSdrhdo_execsql_test skipscan1-1.6sort {
972e5ef4edSdrh  EXPLAIN QUERY PLAN
982e5ef4edSdrh  SELECT a,b,c,d,'|' FROM t1 WHERE c BETWEEN 6 AND 7 ORDER BY a, b, c;
992e5ef4edSdrh} {~/*ORDER BY*/}
1002e5ef4edSdrh
101d2447447Sdrhdo_execsql_test skipscan1-1.7 {
102d2447447Sdrh  SELECT a,b,c,d,'|' FROM t1 WHERE b IN (234, 345) AND c BETWEEN 6 AND 7
103d2447447Sdrh   ORDER BY a, b;
104d2447447Sdrh} {abc 234 6 7 | abc 345 7 8 |}
105d2447447Sdrhdo_execsql_test skipscan1-1.7eqp {
106d2447447Sdrh  EXPLAIN QUERY PLAN
107d2447447Sdrh  SELECT a,b,c,d,'|' FROM t1 WHERE b IN (234, 345) AND c BETWEEN 6 AND 7
108d2447447Sdrh   ORDER BY a, b;
109d2447447Sdrh} {/* USING INDEX t1abc (ANY(a) AND b=? AND c>? AND c<?)*/}
110d2447447Sdrhdo_execsql_test skipscan1-1.7sort {
111d2447447Sdrh  EXPLAIN QUERY PLAN
112d2447447Sdrh  SELECT a,b,c,d,'|' FROM t1 WHERE b IN (234, 345) AND c BETWEEN 6 AND 7
113d2447447Sdrh   ORDER BY a, b;
114d2447447Sdrh} {~/*ORDER BY*/}
115d2447447Sdrh
1162e5ef4edSdrh
117c2b23e7aSdrh# Joins
118c2b23e7aSdrh#
1192e5ef4edSdrhdo_execsql_test skipscan1-1.51 {
120c2b23e7aSdrh  CREATE TABLE t1j(x TEXT, y INTEGER);
121c2b23e7aSdrh  INSERT INTO t1j VALUES('one',1),('six',6),('ninty-nine',99);
1222e5ef4edSdrh  INSERT INTO sqlite_stat1 VALUES('t1j',null,'3');
1232e5ef4edSdrh  ANALYZE sqlite_master;
124c2b23e7aSdrh  SELECT x, a, b, c, d, '|' FROM t1j, t1 WHERE c=y ORDER BY +a;
125c2b23e7aSdrh} {six abc 234 6 7 | six bcd 100 6 11 |}
1262e5ef4edSdrhdo_execsql_test skipscan1-1.51eqp {
127c2b23e7aSdrh  EXPLAIN QUERY PLAN
128c2b23e7aSdrh  SELECT x, a, b, c, d, '|' FROM t1j, t1 WHERE c=y ORDER BY +a;
129c2b23e7aSdrh} {/* INDEX t1abc (ANY(a) AND ANY(b) AND c=?)*/}
130c2b23e7aSdrh
1312e5ef4edSdrhdo_execsql_test skipscan1-1.52 {
132c2b23e7aSdrh  SELECT x, a, b, c, d, '|' FROM t1j LEFT JOIN t1 ON c=y ORDER BY +y, +a;
133c2b23e7aSdrh} {one {} {} {} {} | six abc 234 6 7 | six bcd 100 6 11 | ninty-nine {} {} {} {} |}
1342e5ef4edSdrhdo_execsql_test skipscan1-1.52eqp {
135c2b23e7aSdrh  EXPLAIN QUERY PLAN
136c2b23e7aSdrh  SELECT x, a, b, c, d, '|' FROM t1j LEFT JOIN t1 ON c=y ORDER BY +y, +a;
137c2b23e7aSdrh} {/* INDEX t1abc (ANY(a) AND ANY(b) AND c=?)*/}
138c2b23e7aSdrh
139c2b23e7aSdrhdo_execsql_test skipscan1-2.1 {
140c2b23e7aSdrh  CREATE TABLE t2(a TEXT, b INT, c INT, d INT,
141c2b23e7aSdrh                  PRIMARY KEY(a,b,c));
142c2b23e7aSdrh  INSERT INTO t2 SELECT * FROM t1;
143c2b23e7aSdrh
144c2b23e7aSdrh  /* Fake the sqlite_stat1 table so that the query planner believes
145c2b23e7aSdrh  ** the table contains thousands of rows and that the first few
146c2b23e7aSdrh  ** columns are not selective. */
147c2b23e7aSdrh  ANALYZE;
148c2b23e7aSdrh  UPDATE sqlite_stat1 SET stat='10000 5000 2000 10' WHERE idx NOT NULL;
149c2b23e7aSdrh  ANALYZE sqlite_master;
150c2b23e7aSdrh} {}
151c2b23e7aSdrh
152c2b23e7aSdrhdo_execsql_test skipscan1-2.2 {
15399bbcc82Sdrh  SELECT a,b,c,d,'|' FROM t2 WHERE d<>99 AND b=345 ORDER BY a;
154c2b23e7aSdrh} {abc 345 7 8 | def 345 9 10 |}
155c2b23e7aSdrhdo_execsql_test skipscan1-2.2eqp {
156c2b23e7aSdrh  EXPLAIN QUERY PLAN
15799bbcc82Sdrh  SELECT a,b,c,d,'|' FROM t2 WHERE d<>99 AND b=345 ORDER BY a;
158c2b23e7aSdrh} {/* USING INDEX sqlite_autoindex_t2_1 (ANY(a) AND b=?)*/}
159c2b23e7aSdrhdo_execsql_test skipscan1-2.2sort {
160c2b23e7aSdrh  EXPLAIN QUERY PLAN
16199bbcc82Sdrh  SELECT a,b,c,d,'|' FROM t2 WHERE d<>99 AND b=345 ORDER BY a;
162c2b23e7aSdrh} {~/*ORDER BY*/}
163c2b23e7aSdrh
164c2b23e7aSdrh
165c2b23e7aSdrhdo_execsql_test skipscan1-3.1 {
166c2b23e7aSdrh  CREATE TABLE t3(a TEXT, b INT, c INT, d INT,
167c2b23e7aSdrh                  PRIMARY KEY(a,b,c)) WITHOUT ROWID;
168c2b23e7aSdrh  INSERT INTO t3 SELECT * FROM t1;
169c2b23e7aSdrh
170c2b23e7aSdrh  /* Fake the sqlite_stat1 table so that the query planner believes
171c2b23e7aSdrh  ** the table contains thousands of rows and that the first few
172c2b23e7aSdrh  ** columns are not selective. */
173c2b23e7aSdrh  ANALYZE;
174c2b23e7aSdrh  UPDATE sqlite_stat1 SET stat='10000 5000 2000 10' WHERE idx NOT NULL;
175c2b23e7aSdrh  ANALYZE sqlite_master;
176c2b23e7aSdrh} {}
177c2b23e7aSdrh
178c2b23e7aSdrhdo_execsql_test skipscan1-3.2 {
179c2b23e7aSdrh  SELECT a,b,c,d,'|' FROM t3 WHERE b=345 ORDER BY a;
180c2b23e7aSdrh} {abc 345 7 8 | def 345 9 10 |}
181c2b23e7aSdrhdo_execsql_test skipscan1-3.2eqp {
182c2b23e7aSdrh  EXPLAIN QUERY PLAN
183c2b23e7aSdrh  SELECT a,b,c,d,'|' FROM t3 WHERE b=345 ORDER BY a;
184e96f2df3Sdan} {/* PRIMARY KEY (ANY(a) AND b=?)*/}
185c2b23e7aSdrhdo_execsql_test skipscan1-3.2sort {
186c2b23e7aSdrh  EXPLAIN QUERY PLAN
187c2b23e7aSdrh  SELECT a,b,c,d,'|' FROM t3 WHERE b=345 ORDER BY a;
188c2b23e7aSdrh} {~/*ORDER BY*/}
189c2b23e7aSdrh
1906c1de308Sdrh# Ticket 520070ec7fbaac: Array overrun in the skip-scan optimization
1916c1de308Sdrh# 2013-12-22
1926c1de308Sdrh#
1936c1de308Sdrhdo_execsql_test skipscan1-4.1 {
1946c1de308Sdrh  CREATE TABLE t4(a,b,c,d,e,f,g,h,i);
1956c1de308Sdrh  CREATE INDEX t4all ON t4(a,b,c,d,e,f,g,h);
1966c1de308Sdrh  INSERT INTO t4 VALUES(1,2,3,4,5,6,7,8,9);
1976c1de308Sdrh  ANALYZE;
1986c1de308Sdrh  DELETE FROM sqlite_stat1;
1996c1de308Sdrh  INSERT INTO sqlite_stat1
2006c1de308Sdrh    VALUES('t4','t4all','655360 163840 40960 10240 2560 640 160 40 10');
2016c1de308Sdrh  ANALYZE sqlite_master;
2026c1de308Sdrh  SELECT i FROM t4 WHERE a=1;
2036c1de308Sdrh  SELECT i FROM t4 WHERE b=2;
2046c1de308Sdrh  SELECT i FROM t4 WHERE c=3;
2056c1de308Sdrh  SELECT i FROM t4 WHERE d=4;
2066c1de308Sdrh  SELECT i FROM t4 WHERE e=5;
2076c1de308Sdrh  SELECT i FROM t4 WHERE f=6;
2086c1de308Sdrh  SELECT i FROM t4 WHERE g=7;
2096c1de308Sdrh  SELECT i FROM t4 WHERE h=8;
2106c1de308Sdrh} {9 9 9 9 9 9 9 9}
2116c1de308Sdrh
21289212fb9Sdrh# Make sure skip-scan cost computation in the query planner takes into
21389212fb9Sdrh# account the fact that the seek must occur multiple times.
21489212fb9Sdrh#
21589212fb9Sdrh# Prior to 2014-03-10, the costs were computed incorrectly which would
21689212fb9Sdrh# cause index t5i2 to be used instead of t5i1 on the skipscan1-5.3.
21789212fb9Sdrh#
21889212fb9Sdrhdo_execsql_test skipscan1-5.1 {
21989212fb9Sdrh  CREATE TABLE t5(
22089212fb9Sdrh    id INTEGER PRIMARY KEY,
22189212fb9Sdrh    loc TEXT,
22289212fb9Sdrh    lang INTEGER,
22389212fb9Sdrh    utype INTEGER,
22489212fb9Sdrh    xa INTEGER,
22589212fb9Sdrh    xd INTEGER,
22689212fb9Sdrh    xh INTEGER
22789212fb9Sdrh  );
22889212fb9Sdrh  CREATE INDEX t5i1 on t5(loc, xh, xa, utype, lang);
22989212fb9Sdrh  CREATE INDEX t5i2 ON t5(xd,loc,utype,lang);
23089212fb9Sdrh  EXPLAIN QUERY PLAN
23189212fb9Sdrh    SELECT xh, loc FROM t5 WHERE loc >= 'M' AND loc < 'N';
23289212fb9Sdrh} {/.*COVERING INDEX t5i1 .*/}
23389212fb9Sdrhdo_execsql_test skipscan1-5.2 {
23489212fb9Sdrh  ANALYZE;
23589212fb9Sdrh  DELETE FROM sqlite_stat1;
23689212fb9Sdrh  DROP TABLE IF EXISTS sqlite_stat4;
23789212fb9Sdrh  INSERT INTO sqlite_stat1 VALUES('t5','t5i1','2702931 3 2 2 2 2');
23889212fb9Sdrh  INSERT INTO sqlite_stat1 VALUES('t5','t5i2','2702931 686 2 2 2');
23989212fb9Sdrh  ANALYZE sqlite_master;
24089212fb9Sdrh} {}
24189212fb9Sdrhdb cache flush
24289212fb9Sdrhdo_execsql_test skipscan1-5.3 {
24389212fb9Sdrh  EXPLAIN QUERY PLAN
24489212fb9Sdrh    SELECT xh, loc FROM t5 WHERE loc >= 'M' AND loc < 'N';
24589212fb9Sdrh} {/.*COVERING INDEX t5i1 .*/}
24689212fb9Sdrh
24714f0e212Sdrh# The column used by the skip-scan needs to be sufficiently selective.
24814f0e212Sdrh# See the private email from Adi Zaimi to [email protected] on 2014-09-22.
24914f0e212Sdrh#
25014f0e212Sdrhdb close
25114f0e212Sdrhforcedelete test.db
25214f0e212Sdrhsqlite3 db test.db
25314f0e212Sdrhdo_execsql_test skipscan1-6.1 {
25414f0e212Sdrh  CREATE TABLE t1(a,b,c,d,e,f,g,h varchar(300));
25514f0e212Sdrh  CREATE INDEX t1ab ON t1(a,b);
25614f0e212Sdrh  ANALYZE sqlite_master;
25714f0e212Sdrh  -- Only two distinct values for the skip-scan column.  Skip-scan is not used.
25814f0e212Sdrh  INSERT INTO sqlite_stat1 VALUES('t1','t1ab','500000 250000 125000');
25914f0e212Sdrh  ANALYZE sqlite_master;
26014f0e212Sdrh  EXPLAIN QUERY PLAN SELECT * FROM t1 WHERE b=1;
26114f0e212Sdrh} {~/ANY/}
26214f0e212Sdrhdo_execsql_test skipscan1-6.2 {
26314f0e212Sdrh  -- Four distinct values for the skip-scan column.  Skip-scan is used.
26414f0e212Sdrh  UPDATE sqlite_stat1 SET stat='500000 250000 62500';
26514f0e212Sdrh  ANALYZE sqlite_master;
26614f0e212Sdrh  EXPLAIN QUERY PLAN SELECT * FROM t1 WHERE b=1;
26714f0e212Sdrh} {/ANY.a. AND b=/}
26814f0e212Sdrhdo_execsql_test skipscan1-6.3 {
26914f0e212Sdrh  -- Two distinct values for the skip-scan column again.  Skip-scan is not used.
27014f0e212Sdrh  UPDATE sqlite_stat1 SET stat='500000 125000 62500';
27114f0e212Sdrh  ANALYZE sqlite_master;
27214f0e212Sdrh  EXPLAIN QUERY PLAN SELECT * FROM t1 WHERE b=1;
27314f0e212Sdrh} {~/ANY/}
27489212fb9Sdrh
275f9df2fbdSdrh# If the sqlite_stat1 entry includes the "noskipscan" token, then never use
276f9df2fbdSdrh# skipscan with that index.
277f9df2fbdSdrh#
278f9df2fbdSdrhdo_execsql_test skipscan1-7.1 {
279f9df2fbdSdrh  UPDATE sqlite_stat1 SET stat='500000 125000 1 sz=100';
280f9df2fbdSdrh  ANALYZE sqlite_master;
281f9df2fbdSdrh  EXPLAIN QUERY PLAN SELECT * FROM t1 WHERE b=1;
282f9df2fbdSdrh} {/ANY/}
283f9df2fbdSdrhdo_execsql_test skipscan1-7.2 {
284f9df2fbdSdrh  UPDATE sqlite_stat1 SET stat='500000 125000 1 noskipscan sz=100';
285f9df2fbdSdrh  ANALYZE sqlite_master;
286f9df2fbdSdrh  EXPLAIN QUERY PLAN SELECT * FROM t1 WHERE b=1;
287f9df2fbdSdrh} {~/ANY/}
288f9df2fbdSdrhdo_execsql_test skipscan1-7.3 {
289f9df2fbdSdrh  UPDATE sqlite_stat1 SET stat='500000 125000 1 sz=100 noskipscan';
290f9df2fbdSdrh  ANALYZE sqlite_master;
291f9df2fbdSdrh  EXPLAIN QUERY PLAN SELECT * FROM t1 WHERE b=1;
292f9df2fbdSdrh} {~/ANY/}
293f9df2fbdSdrh
294d3e3f0b4Sdrh# Ticket 8fd39115d8f46ece70e7d4b3c481d1bd86194746  2015-07-23
295d3e3f0b4Sdrh# Incorrect code generated for a skipscan within an OR optimization
296d3e3f0b4Sdrh# on a WITHOUT ROWID table.
297d3e3f0b4Sdrh#
298d3e3f0b4Sdrhdo_execsql_test skipscan1-8.1 {
299d3e3f0b4Sdrh  DROP TABLE IF EXISTS t1;
300d3e3f0b4Sdrh  CREATE TABLE t1(x, y, PRIMARY KEY(x,y)) WITHOUT ROWID;
301d3e3f0b4Sdrh  INSERT INTO t1(x,y) VALUES(1,'AB');
302d3e3f0b4Sdrh  INSERT INTO t1(x,y) VALUES(2,'CD');
303d3e3f0b4Sdrh  ANALYZE;
304d3e3f0b4Sdrh  DROP TABLE IF EXISTS sqlite_stat4;
305d3e3f0b4Sdrh  DELETE FROM sqlite_stat1;
306d3e3f0b4Sdrh  INSERT INTO sqlite_stat1(tbl,idx,stat) VALUES('t1','t1','1000000 100 1');
307d3e3f0b4Sdrh  ANALYZE sqlite_master;
308d3e3f0b4Sdrh  SELECT * FROM t1
309d3e3f0b4Sdrh   WHERE (y = 'AB' AND x <= 4)
310d3e3f0b4Sdrh      OR (y = 'EF' AND x = 5);
311d3e3f0b4Sdrh} {1 AB}
312d3e3f0b4Sdrhdo_execsql_test skipscan1-8.1eqp {
313d3e3f0b4Sdrh  EXPLAIN QUERY PLAN
314d3e3f0b4Sdrh  SELECT * FROM t1
315d3e3f0b4Sdrh   WHERE (y = 'AB' AND x <= 4)
316d3e3f0b4Sdrh      OR (y = 'EF' AND x = 5);
317d3e3f0b4Sdrh} {/ANY/}
318d3e3f0b4Sdrhdo_execsql_test skipscan1-8.2 {
319d3e3f0b4Sdrh  SELECT * FROM t1
320d3e3f0b4Sdrh   WHERE y = 'AB' OR (y = 'CD' AND x = 2)
321d3e3f0b4Sdrh  ORDER BY +x;
322d3e3f0b4Sdrh} {1 AB 2 CD}
323d3e3f0b4Sdrh
3249a2e5169Sdrh# Segfault reported on the mailing list by Keith Medcalf on 2016-09-18.
3259a2e5169Sdrh# A skip-scan with a "column IN (SELECT ...)" on the second term of the
3269a2e5169Sdrh# index.
3279a2e5169Sdrh#
3289a2e5169Sdrhdo_execsql_test skipscan1-9.2 {
3299a2e5169Sdrh  CREATE TABLE t9a(a,b,c);
3309a2e5169Sdrh  CREATE INDEX t9a_ab ON t9a(a,b);
3319a2e5169Sdrh  CREATE TABLE t9b(x,y);
3329a2e5169Sdrh  ANALYZE sqlite_master;
3339a2e5169Sdrh  INSERT INTO sqlite_stat1 VALUES('t9a','t9a_ab','1000000 250000 1');
3349a2e5169Sdrh  ANALYZE sqlite_master;
3359a2e5169Sdrh  EXPLAIN QUERY PLAN
3369a2e5169Sdrh  SELECT * FROM t9a WHERE b IN (SELECT x FROM t9b WHERE y!=5);
3379a2e5169Sdrh} {/USING INDEX t9a_ab .ANY.a. AND b=./}
3389a2e5169Sdrh
339e8825519Sdan
340e8825519Sdanoptimization_control db skip-scan 0
341e8825519Sdando_execsql_test skipscan1-9.3 {
342e8825519Sdan  EXPLAIN QUERY PLAN
343e8825519Sdan  SELECT  * FROM t9a WHERE b IN (SELECT x FROM t9b WHERE y!=5);
344*8210233cSdrh} {/{SCAN t9a}/}
345e8825519Sdanoptimization_control db skip-scan 1
346e8825519Sdan
3476cf3009fSdando_execsql_test skipscan1-2.1 {
3486cf3009fSdan  CREATE TABLE t6(a TEXT, b INT, c INT, d INT);
3496cf3009fSdan  CREATE INDEX t6abc ON t6(a,b,c);
3506cf3009fSdan  INSERT INTO t6 VALUES('abc',123,4,5);
3516cf3009fSdan
3526cf3009fSdan  ANALYZE;
3536cf3009fSdan  DELETE FROM sqlite_stat1;
3546cf3009fSdan  INSERT INTO sqlite_stat1 VALUES('t6','t6abc','10000 5000 2000 10');
3556cf3009fSdan  ANALYZE sqlite_master;
3566cf3009fSdan  DELETE FROM t6;
3576cf3009fSdan} {}
3586cf3009fSdan
3596cf3009fSdando_execsql_test skipscan1-2.2eqp {
3606cf3009fSdan  EXPLAIN QUERY PLAN
3616cf3009fSdan  SELECT a,b,c,d,'|' FROM t6 WHERE d<>99 AND b=345 ORDER BY a;
3626cf3009fSdan} {/* USING INDEX t6abc (ANY(a) AND b=?)*/}
3636cf3009fSdando_execsql_test skipscan1-2.2 {
3646cf3009fSdan  SELECT a,b,c,d,'|' FROM t6 WHERE d<>99 AND b=345 ORDER BY a;
3656cf3009fSdan} {}
3666cf3009fSdan
3676cf3009fSdando_execsql_test skipscan1-2.3eqp {
3686cf3009fSdan  EXPLAIN QUERY PLAN
3696cf3009fSdan  SELECT a,b,c,d,'|' FROM t6 WHERE d<>99 AND b=345 ORDER BY a DESC;
3706cf3009fSdan} {/* USING INDEX t6abc (ANY(a) AND b=?)*/}
3716cf3009fSdando_execsql_test skipscan1-2.3 {
3726cf3009fSdan  SELECT a,b,c,d,'|' FROM t6 WHERE d<>99 AND b=345 ORDER BY a DESC;
3736cf3009fSdan} {}
3746cf3009fSdan
375822bc969Sdrh# 2019-07-29 Ticket ced41c7c7d6b4d36
3762ad07d96Sdrh# A skipscan query is not order-distinct
377822bc969Sdrh#
378822bc969Sdrhdb close
379822bc969Sdrhsqlite3 db :memory:
380822bc969Sdrhdo_execsql_test skipscan1-3.1 {
381822bc969Sdrh  CREATE TABLE t1 (c1, c2, c3, c4, PRIMARY KEY(c4, c3));
3822ad07d96Sdrh  INSERT INTO t1 VALUES(3,0,1,NULL);
3832ad07d96Sdrh  INSERT INTO t1 VALUES(0,4,1,NULL);
3842ad07d96Sdrh  INSERT INTO t1 VALUES(5,6,1,NULL);
3852ad07d96Sdrh  INSERT INTO t1 VALUES(0,4,1,NULL);
386822bc969Sdrh  ANALYZE sqlite_master;
387822bc969Sdrh  INSERT INTO sqlite_stat1 VALUES('t1','sqlite_autoindex_t1_1','18 18 6');
388822bc969Sdrh  ANALYZE sqlite_master;
389822bc969Sdrh  SELECT DISTINCT quote(c1), quote(c2), quote(c3), quote(c4), '|'
390822bc969Sdrh    FROM t1 WHERE t1.c3 = 1;
3912ad07d96Sdrh} {3 0 1 NULL | 0 4 1 NULL | 5 6 1 NULL |}
3922ad07d96Sdrhdo_eqp_test skipscan1-3.2 {
3932ad07d96Sdrh  SELECT DISTINCT quote(c1), quote(c2), quote(c3), quote(c4), '|'
3942ad07d96Sdrh    FROM t1 WHERE t1.c3 = 1;
3952ad07d96Sdrh} {
3962ad07d96Sdrh  QUERY PLAN
397*8210233cSdrh  |--SEARCH t1 USING INDEX sqlite_autoindex_t1_1 (ANY(c4) AND c3=?)
3982ad07d96Sdrh  `--USE TEMP B-TREE FOR DISTINCT
3992ad07d96Sdrh}
400822bc969Sdrh
401b592d47aSdrh# 2020-01-06 ticket 304017f5f04a0035
402b592d47aSdrh#
403b592d47aSdrhreset_db
404b592d47aSdrhdo_execsql_test skipscan1-4.10 {
405b592d47aSdrh  CREATE TABLE t1(a,b INT);
406b592d47aSdrh  INSERT INTO t1(a,b) VALUES(1,2),(3,3),(4,5);
407b592d47aSdrh  CREATE UNIQUE INDEX i1 ON t1(b,b,a,a,a,a,a,b,a);
408b592d47aSdrh  ANALYZE;
409b592d47aSdrh  DROP TABLE IF EXISTS sqlite_stat4;
410b592d47aSdrh  INSERT INTO sqlite_stat1 VALUES('t1','i1','30 30 30 2 2 2 2 2 2 2');
411b592d47aSdrh  ANALYZE sqlite_master;
412b592d47aSdrh
413b592d47aSdrh  SELECT DISTINCT a
414b592d47aSdrh    FROM t1
415b592d47aSdrh   WHERE a = b
416b592d47aSdrh     AND a = 3
417b592d47aSdrh     AND b IN (1,3,2,4)
418b592d47aSdrh     AND b >= 0
419b592d47aSdrh     AND a <= 10;
420b592d47aSdrh} {3}
421b592d47aSdrh
422c2b23e7aSdrhfinish_test
423