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 the push-down optimizations.
15 # There are two different meanings for "push-down optimization".
17 # (1) "MySQL push-down" means that WHERE clause terms that can be
18 # evaluated using only the index and without reference to the
19 # table are run first, so that if they are false, unnecessary table
20 # seeks are avoided. See https://sqlite.org/src/info/d7bb79ed3a40419d
23 # (2) "WHERE-clause pushdown" means to push WHERE clause terms in
24 # outer queries down into subqueries. See
25 # https://sqlite.org/src/info/6df18e949d367629 from 2015-06-02.
27 # This module started out as tests for MySQL push-down only. But because
28 # of naming ambiguity, it has picked up test cases for WHERE-clause push-down
32 set testdir [file dirname $argv0]
33 source $testdir/tester.tcl
34 set testprefix pushdown
37 CREATE TABLE t1(a, b, c);
38 INSERT INTO t1 VALUES(1, 'b1', 'c1');
39 INSERT INTO t1 VALUES(2, 'b2', 'c2');
40 INSERT INTO t1 VALUES(3, 'b3', 'c3');
41 INSERT INTO t1 VALUES(4, 'b4', 'c4');
42 CREATE INDEX i1 ON t1(a, c);
53 execsql { SELECT * FROM t1 WHERE a=2 AND f(b) AND f(c) }
59 execsql { SELECT * FROM t1 WHERE a=3 AND f(c) AND f(b) }
65 CREATE INDEX i1 ON t1(a, b);
69 execsql { SELECT * FROM t1 WHERE a=2 AND f(b) AND f(c) }
75 execsql { SELECT * FROM t1 WHERE a=3 AND f(c) AND f(b) }
79 #-----------------------------------------------
82 CREATE TABLE u1(a, b, c);
83 CREATE TABLE u2(x, y, z);
85 INSERT INTO u1 VALUES('a1', 'b1', 'c1');
86 INSERT INTO u2 VALUES('a1', 'b1', 'c1');
92 SELECT * FROM u1 WHERE f('one')=123 AND 123=(
93 SELECT x FROM u2 WHERE x=a AND f('two')
102 SELECT * FROM u1 WHERE 123=(
103 SELECT x FROM u2 WHERE x=a AND f('two')
109 # 2022-11-25 dbsqlfuzz crash-3a548de406a50e896c1bf7142692d35d339d697f
110 # Disable the WHERE-clause push-down optimization for compound subqueries
111 # if any arm of the compound has an incompatible affinity.
114 do_execsql_test 3.1 {
115 CREATE TABLE t0(c0 INT);
116 INSERT INTO t0 VALUES(0);
117 CREATE TABLE t1_a(a INTEGER PRIMARY KEY, b TEXT);
118 INSERT INTO t1_a VALUES(1,'one');
119 CREATE TABLE t1_b(c INTEGER PRIMARY KEY, d TEXT);
120 INSERT INTO t1_b VALUES(2,'two');
121 CREATE VIEW v0 AS SELECT CAST(t0.c0 AS INTEGER) AS c0 FROM t0;
122 CREATE VIEW v1(a,b) AS SELECT a, b FROM t1_a UNION ALL SELECT c, 0 FROM t1_b;
123 SELECT v1.a, quote(v1.b), t0.c0 AS cd FROM t0 LEFT JOIN v0 ON v0.c0!=0,v1;
128 do_execsql_test 3.2 {
129 SELECT a, quote(b), cd FROM (
130 SELECT v1.a, v1.b, t0.c0 AS cd FROM t0 LEFT JOIN v0 ON v0.c0!=0, v1
131 ) WHERE a=2 AND b='0' AND cd=0;
133 do_execsql_test 3.3 {
134 SELECT a, quote(b), cd FROM (
135 SELECT v1.a, v1.b, t0.c0 AS cd FROM t0 LEFT JOIN v0 ON v0.c0!=0, v1
136 ) WHERE a=1 AND b='one' AND cd=0;
138 do_execsql_test 3.4 {
139 SELECT a, quote(b), cd FROM (
140 SELECT v1.a, v1.b, t0.c0 AS cd FROM t0 LEFT JOIN v0 ON v0.c0!=0, v1
141 ) WHERE a=2 AND b=0 AND cd=0;
146 # 2023-02-22 https://sqlite.org/forum/forumpost/bcc4375032
147 # Performance regression caused by check-in [1ad41840c5e0fa70] from 2022-11-25.
148 # That check-in added a new restriction on push-down. The new restriction is
149 # no longer necessary after check-in [27655c9353620aa5] from 2022-12-14.
151 do_execsql_test 3.5 {
152 DROP TABLE IF EXISTS t1;
153 CREATE TABLE t1(a INT, b INT, c TEXT, PRIMARY KEY(a,b)) WITHOUT ROWID;
154 INSERT INTO t1(a,b,c) VALUES
158 DROP TABLE IF EXISTS t2;
159 CREATE TABLE t2(a INT, b INT, c TEXT, PRIMARY KEY(a,b)) WITHOUT ROWID;
160 INSERT INTO t2(a,b,c) VALUES
165 SELECT a, b, c FROM t1
167 SELECT a, b, 'xyz' FROM t2;
168 SELECT * FROM v3 WHERE a=2 AND b=200;
169 } {2 200 def 2 200 xyz}
171 SELECT * FROM v3 WHERE a=2 AND b=200;
176 | |--LEFT-MOST SUBQUERY
177 | | `--SEARCH t1 USING PRIMARY KEY (a=? AND b=?)
179 | `--SEARCH t2 USING PRIMARY KEY (a=? AND b=?)
182 # ^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^
183 # We want both arms of the compound subquery to use the
186 # The following is a test of the count-of-view optimization. This does
187 # not have anything to do with push-down. It is here because this is a
188 # convenient place to put the test.
190 do_execsql_test 3.7 {
191 SELECT count(*) FROM v3;
194 SELECT count(*) FROM v3;
198 |--SCALAR SUBQUERY xxxxxx
200 `--SCALAR SUBQUERY xxxxxx
203 # ^^^^^^^^^^^^^^^^^^^^
204 # The query should be converted into:
205 # SELECT (SELECT count(*) FROM t1)+(SELECT count(*) FROM t2)
207 # 2023-05-09 https://sqlite.org/forum/forumpost/a7d4be7fb6
208 # Restriction (9) on the WHERE-clause push-down optimization.
212 do_execsql_test 4.1 {
213 CREATE TABLE t1(a INT);
214 CREATE TABLE t2(b INT);
215 CREATE TABLE t3(c INT);
216 INSERT INTO t3(c) VALUES(3);
217 CREATE TABLE t4(d INT);
218 CREATE TABLE t5(e INT);
219 INSERT INTO t5(e) VALUES(5);
220 CREATE VIEW v6(f,g) AS SELECT d, e FROM t4 RIGHT JOIN t5 ON true;
221 SELECT * FROM t1 JOIN t2 ON false RIGHT JOIN t3 ON true CROSS JOIN v6;
223 do_execsql_test 4.2 {
224 SELECT * FROM v6 JOIN t5 ON false RIGHT JOIN t3 ON true;
226 do_execsql_test 4.3 {
227 SELECT * FROM t1 JOIN t2 ON false JOIN v6 ON true RIGHT JOIN t3 ON true;
230 # 2023-05-15 https://sqlite.org/forum/forumpost/f3f546025a
231 # This is restriction (6) on sqlite3ExprIsSingleTableConstraint().
232 # That restriction (now) used to implement restriction (9) on push-down.
233 # It is used for other things too, so it is not purely a push-down
234 # restriction. But it seems convenient to put it here.
238 do_execsql_test 5.0 {
239 CREATE TABLE t1(a INT); INSERT INTO t1 VALUES(1);
240 CREATE TABLE t2(b INT); INSERT INTO t2 VALUES(2);
241 CREATE TABLE t3(c INT); INSERT INTO t3 VALUES(3);
242 CREATE TABLE t4(d INT); INSERT INTO t4 VALUES(4);
243 CREATE TABLE t5(e INT); INSERT INTO t5 VALUES(5);
245 FROM t1 JOIN t2 ON null RIGHT JOIN t3 ON true
246 LEFT JOIN (t4 JOIN t5 ON d+1=e) ON d=4
252 # Allow push-down of operators of the form "expr IN table".
255 do_execsql_test 6.0 {
256 CREATE TABLE t01(w,x,y,z);
257 CREATE TABLE t02(w,x,y,z);
258 CREATE VIEW t0(w,x,y,z) AS
259 SELECT w,x,y,z FROM t01 UNION ALL SELECT w,x,y,z FROM t02;
260 CREATE INDEX t01x ON t01(w,x,y);
261 CREATE INDEX t02x ON t02(w,x,y);
262 CREATE VIEW v1(k) AS VALUES(77),(88),(99);
264 INSERT INTO k1 SELECT * FROM v1;
267 WITH k(n) AS (VALUES(77),(88),(99))
268 SELECT max(z) FROM t0 WHERE w=123 AND x IN k AND y BETWEEN 44 AND 55;
273 | |--LEFT-MOST SUBQUERY
274 | | |--SEARCH t01 USING INDEX t01x (w=? AND x=? AND y>? AND y<?)
275 | | `--LIST SUBQUERY xxxxxx
277 | | | `--SCAN 3 CONSTANT ROWS
280 | |--SEARCH t02 USING INDEX t02x (w=? AND x=? AND y>? AND y<?)
281 | `--LIST SUBQUERY xxxxxx
284 `--LIST SUBQUERY xxxxxx
287 # ^^^^--- The key feature above is that the SEARCH for each subquery
288 # uses all three fields of the index w, x, and y. Prior to the push-down
289 # of "expr IN table", only the w term of the index would be used. Similar
290 # for the following tests:
293 SELECT max(z) FROM t0 WHERE w=123 AND x IN v1 AND y BETWEEN 44 AND 55;
298 | |--LEFT-MOST SUBQUERY
299 | | |--SEARCH t01 USING INDEX t01x (w=? AND x=? AND y>? AND y<?)
300 | | `--LIST SUBQUERY xxxxxx
302 | | | `--SCAN 3 CONSTANT ROWS
305 | |--SEARCH t02 USING INDEX t02x (w=? AND x=? AND y>? AND y<?)
306 | `--LIST SUBQUERY xxxxxx
308 | | `--SCAN 3 CONSTANT ROWS
311 `--LIST SUBQUERY xxxxxx
313 | `--SCAN 3 CONSTANT ROWS
317 SELECT max(z) FROM t0 WHERE w=123 AND x IN k1 AND y BETWEEN 44 AND 55;
322 | |--LEFT-MOST SUBQUERY
323 | | |--SEARCH t01 USING INDEX t01x (w=? AND x=? AND y>? AND y<?)
324 | | `--LIST SUBQUERY xxxxxx
327 | |--SEARCH t02 USING INDEX t02x (w=? AND x=? AND y>? AND y<?)
328 | `--LIST SUBQUERY xxxxxx
331 `--LIST SUBQUERY xxxxxx