3 # The author disclaims copyright to this source code. In place of
4 # a legal notice, here is a blessing:
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.
10 #***********************************************************************
12 # Test cases for query planning decisions.
16 # The tests in this file demonstrate the behaviour of the query planner
17 # in determining the order in which joined tables are scanned.
19 # Assume there are two tables being joined - t1 and t2. Each has a cost
20 # if it is the outer loop, and a cost if it is the inner loop. As follows:
22 # t1(outer) - cost of scanning t1 as the outer loop.
23 # t1(inner) - cost of scanning t1 as the inner loop.
24 # t2(outer) - cost of scanning t2 as the outer loop.
25 # t2(inner) - cost of scanning t2 as the inner loop.
27 # Depending on the order in which the planner nests the scans, the total
28 # cost of the join query is one of:
30 # t1(outer) * t2(inner)
31 # t2(outer) * t1(inner)
33 # The tests in this file attempt to verify that the planner nests joins in
34 # the correct order when the following are true:
36 # + (t1(outer) * t2(inner)) > (t1(inner) * t2(outer)
37 # + t1(outer) < t2(outer)
39 # In other words, when the best overall query plan has t2 as the outer loop,
40 # but when the outer loop is considered independent of the inner, t1 is the
41 # most efficient choice.
43 # In order to make them more predictable, automatic indexes are turned off for
44 # the tests in this file.
47 set testdir [file dirname $argv0]
48 source $testdir/tester.tcl
52 PRAGMA automatic_index = 0;
53 CREATE TABLE t1(a, b, c);
54 CREATE TABLE t2(d, e, f);
55 CREATE UNIQUE INDEX i1 ON t1(a);
56 CREATE UNIQUE INDEX i2 ON t2(d);
60 1 "SELECT * FROM t1, t2 WHERE t1.a=t2.e AND t2.d<t1.b AND t1.c!=10"
61 2 "SELECT * FROM t2, t1 WHERE t1.a=t2.e AND t2.d<t1.b AND t1.c!=10"
62 3 "SELECT * FROM t2 CROSS JOIN t1 WHERE t1.a=t2.e AND t2.d<t1.b AND t1.c!=10"
65 db eval "EXPLAIN QUERY PLAN $sql"
66 } {/.*SCAN t2\y.*SEARCH t1\y.*/}
72 CREATE TABLE t1(a, b, c);
73 CREATE TABLE t2(d, e, f);
75 CREATE UNIQUE INDEX i1 ON t1(a);
76 CREATE UNIQUE INDEX i2 ON t1(b);
77 CREATE UNIQUE INDEX i3 ON t2(d);
81 1 "SELECT * FROM t1, t2 WHERE t1.a>? AND t2.d>t1.c AND t1.b=t2.e"
82 2 "SELECT * FROM t2, t1 WHERE t1.a>? AND t2.d>t1.c AND t1.b=t2.e"
83 3 "SELECT * FROM t2 CROSS JOIN t1 WHERE t1.a>? AND t2.d>t1.c AND t1.b=t2.e"
86 db eval "EXPLAIN QUERY PLAN $sql"
87 } {/.*SCAN t2\y.*SEARCH t1\y.*/}
93 CREATE TABLE t1(a, b, c);
94 CREATE TABLE t2(d, e, f);
96 CREATE UNIQUE INDEX i1 ON t1(a, b);
97 CREATE INDEX i2 ON t2(d);
101 1 {SELECT t1.a, t1.b, t2.d, t2.e FROM t1, t2
102 WHERE t2.d=t1.b AND t1.a=(t2.d+1) AND t1.b = (t2.e+1)}
104 2 {SELECT t1.a, t1.b, t2.d, t2.e FROM t2, t1
105 WHERE t2.d=t1.b AND t1.a=(t2.d+1) AND t1.b = (t2.e+1)}
107 3 {SELECT t1.a, t1.b, t2.d, t2.e FROM t2 CROSS JOIN t1
108 WHERE t2.d=t1.b AND t1.a=(t2.d+1) AND t1.b = (t2.e+1)}
111 db eval "EXPLAIN QUERY PLAN $sql"
112 } {/.*SCAN t2\y.*SEARCH t1\y.*/}
115 do_execsql_test 4.0 {
116 CREATE TABLE t4(a,b,c,d,e, PRIMARY KEY(a,b,c));
117 CREATE INDEX t4adc ON t4(a,d,c);
118 CREATE UNIQUE INDEX t4aebc ON t4(a,e,b,c);
119 EXPLAIN QUERY PLAN SELECT rowid FROM t4 WHERE a=? AND b=?;
122 #-------------------------------------------------------------------------
123 # Test the following case:
125 # ... FROM t1, t2 WHERE (
126 # t2.rowid = +t1.rowid OR (t2.f2 = t1.f1 AND t1.f1!=-1)
129 # where there is an index on t2(f2). The planner should use "t1" as the
130 # outer loop. The inner loop, on "t2", is an OR optimization. One pass
137 # t2.f2=$1 AND $1!=-1
139 # the test is to ensure that on the second pass, the ($1!=-1) condition
140 # is tested before any seek operations are performed - i.e. outside of
141 # the loop through the f2=$1 range of the t2(f2) index.
144 do_execsql_test 5.0 {
147 CREATE INDEX t2f ON t2(f2);
149 INSERT INTO t1 VALUES(-1);
150 INSERT INTO t1 VALUES(-1);
151 INSERT INTO t1 VALUES(-1);
152 INSERT INTO t1 VALUES(-1);
155 SELECT 1 UNION ALL SELECT i+1 FROM w WHERE i<1000
157 INSERT INTO t2 SELECT -1 FROM w;
160 do_execsql_test 5.1 {
161 SELECT count(*) FROM t1, t2 WHERE t2.rowid = +t1.rowid
163 do_test 5.2 { expr [db status vmstep]<200 } 1
165 do_execsql_test 5.3 {
166 SELECT count(*) FROM t1, t2 WHERE (
167 t2.rowid = +t1.rowid OR t2.f2 = t1.f1
170 do_test 5.4 { expr [db status vmstep]>1000 } 1
172 do_execsql_test 5.5 {
173 SELECT count(*) FROM t1, t2 WHERE (
174 t2.rowid = +t1.rowid OR (t2.f2 = t1.f1 AND t1.f1!=-1)
177 do_test 5.6 { expr [db status vmstep]<200 } 1
179 # 2017-09-04 ticket b899b6042f97f52d
180 # Segfault on correlated subquery...
182 ifcapable json1&&vtab {
183 do_execsql_test 6.1 {
185 SELECT * FROM t6 WHERE 1 IN (SELECT value FROM json_each(x));
188 do_execsql_test 6.2 {
190 CREATE TABLE t6(a,b,c);
191 INSERT INTO t6 VALUES
192 (0,null,'{"a":0,"b":[3,4,5],"c":{"x":4.5,"y":7.8}}'),
193 (1,null,'{"a":1,"b":[3,4,5],"c":{"x":4.5,"y":7.8}}'),
194 (2,null,'{"a":9,"b":[3,4,5],"c":{"x":4.5,"y":7.8}}');
196 WHERE (EXISTS (SELECT 1 FROM json_each(t6.c) AS x WHERE x.value=1));
197 } {1 {} {{"a":1,"b":[3,4,5],"c":{"x":4.5,"y":7.8}}}}
199 # Another test case derived from a posting by Wout Mertens on the
200 # sqlite-users mailing list on 2017-10-04.
201 do_execsql_test 6.3 {
202 DROP TABLE IF EXISTS t;
203 CREATE TABLE t(json JSON);
205 WHERE(EXISTS(SELECT 1 FROM json_each(t.json,"$.foo") j
206 WHERE j.value = 'meep'));
208 do_execsql_test 6.4 {
209 INSERT INTO t VALUES('{"xyzzy":null}');
210 INSERT INTO t VALUES('{"foo":"meep","other":12345}');
211 INSERT INTO t VALUES('{"foo":"bingo","alt":5.25}');
213 WHERE(EXISTS(SELECT 1 FROM json_each(t.json,"$.foo") j
214 WHERE j.value = 'meep'));
215 } {{{"foo":"meep","other":12345}}}
219 # Ticket https://sqlite.org/src/tktview/ec32177c99ccac2b180fd3ea2083
220 # Incorrect result when using the new OR clause factoring optimization
222 # This is the original test case as reported on the sqlite-users mailing
225 do_execsql_test 7.1 {
226 DROP TABLE IF EXISTS cd;
227 CREATE TABLE cd ( cdid INTEGER PRIMARY KEY NOT NULL, genreid integer );
228 CREATE INDEX cd_idx_genreid ON cd (genreid);
229 INSERT INTO cd ( cdid, genreid ) VALUES
240 FROM cd rownum__emulation
243 me.genreid IS NOT NULL
245 rownum__emulation.genreid IS NULL
249 me.genreid IS NOT NULL
251 rownum__emulation.genreid IS NOT NULL
253 rownum__emulation.genreid < me.genreid
257 ( me.genreid = rownum__emulation.genreid OR ( me.genreid IS NULL
258 AND rownum__emulation.genreid IS NULL ) )
260 rownum__emulation.cdid > me.cdid
265 # Simplified test cases from the ticket
267 do_execsql_test 7.2 {
268 DROP TABLE IF EXISTS t1;
269 DROP TABLE IF EXISTS t2;
270 CREATE TABLE t1(a INTEGER PRIMARY KEY, b);
271 INSERT INTO t1(a,b) VALUES(1,1);
272 CREATE TABLE t2(aa INTEGER PRIMARY KEY, bb);
273 INSERT INTO t2(aa,bb) VALUES(1,1),(2,NULL),(3,NULL);
275 SELECT COUNT(*) FROM t2
276 WHERE ( t1.b IS NOT NULL AND t2.bb IS NULL )
278 OR ( t1.b IS t2.bb AND t2.aa > t1.a )
283 # The fix for ticket ec32177c99ccac2b180fd3ea2083 only makes a difference
284 # in the output when there is a TERM_VNULL entry in the WhereClause array.
285 # And TERM_VNULL entries are only generated when compiling with
286 # SQLITE_ENABLE_STAT4. Nevertheless, it is correct that TERM_VIRTUAL terms
287 # should not participate in the factoring optimization. In all cases other
288 # than TERM_VNULL, participation is harmless, but it does consume a few
291 # The following test verifies that the TERM_VIRTUAL terms resulting from
292 # a GLOB operator do not appear anywhere in the generated code. This
293 # confirms that the problem is fixed, even on builds that omit STAT4.
295 do_execsql_test 7.3 {
296 DROP TABLE IF EXISTS t1;
297 DROP TABLE IF EXISTS t2;
298 CREATE TABLE t1(a INTEGER PRIMARY KEY, b TEXT);
299 INSERT INTO t1(a,b) VALUES(1,'abcxyz');
300 CREATE TABLE t2(aa INTEGER PRIMARY KEY, bb TEXT);
301 INSERT INTO t2(aa,bb) VALUES(1,'abc'),(2,'wxyz'),(3,'xyz');
302 CREATE INDEX t2bb ON t2(bb);
304 SELECT COUNT(*) FROM t2
305 WHERE ( t1.b GLOB 'a*z' AND t2.bb='xyz' )