blob: e549c4934358d7d1704f70de141ee6a23e63c185 [file] [log] [blame]
drhb733d032004-01-24 20:18:12 +00001# 2002 May 24
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.
12#
13# This file implements tests for joins, including outer joins.
14#
drhb733d032004-01-24 20:18:12 +000015
16set testdir [file dirname $argv0]
17source $testdir/tester.tcl
danf112f0b2017-01-10 17:37:49 +000018set testprefix join2
drhb733d032004-01-24 20:18:12 +000019
20do_test join2-1.1 {
21 execsql {
22 CREATE TABLE t1(a,b);
23 INSERT INTO t1 VALUES(1,11);
24 INSERT INTO t1 VALUES(2,22);
25 INSERT INTO t1 VALUES(3,33);
26 SELECT * FROM t1;
27 }
28} {1 11 2 22 3 33}
29do_test join2-1.2 {
30 execsql {
31 CREATE TABLE t2(b,c);
32 INSERT INTO t2 VALUES(11,111);
33 INSERT INTO t2 VALUES(33,333);
34 INSERT INTO t2 VALUES(44,444);
35 SELECT * FROM t2;
36 }
37} {11 111 33 333 44 444};
38do_test join2-1.3 {
39 execsql {
40 CREATE TABLE t3(c,d);
41 INSERT INTO t3 VALUES(111,1111);
42 INSERT INTO t3 VALUES(444,4444);
43 INSERT INTO t3 VALUES(555,5555);
44 SELECT * FROM t3;
45 }
46} {111 1111 444 4444 555 5555}
47
48do_test join2-1.4 {
49 execsql {
50 SELECT * FROM
51 t1 NATURAL JOIN t2 NATURAL JOIN t3
52 }
53} {1 11 111 1111}
54do_test join2-1.5 {
55 execsql {
56 SELECT * FROM
57 t1 NATURAL JOIN t2 NATURAL LEFT OUTER JOIN t3
58 }
59} {1 11 111 1111 3 33 333 {}}
60do_test join2-1.6 {
61 execsql {
62 SELECT * FROM
63 t1 NATURAL LEFT OUTER JOIN t2 NATURAL JOIN t3
64 }
65} {1 11 111 1111}
drhec270772022-04-11 18:54:23 +000066do_test join2-1.6-rj {
67 execsql {
68 SELECT * FROM
69 t2 NATURAL RIGHT OUTER JOIN t1 NATURAL JOIN t3
70 }
71} {11 111 1 1111}
danielk19773e8c37e2005-01-21 03:12:14 +000072ifcapable subquery {
73 do_test join2-1.7 {
74 execsql {
75 SELECT * FROM
76 t1 NATURAL LEFT OUTER JOIN (t2 NATURAL JOIN t3)
77 }
78 } {1 11 111 1111 2 22 {} {} 3 33 {} {}}
drhec270772022-04-11 18:54:23 +000079 do_test join2-1.7-rj {
80 execsql {
drh6fda1762022-04-16 23:38:29 +000081 SELECT a, b, c, d FROM
82 t2 NATURAL JOIN t3 NATURAL RIGHT JOIN t1
drhec270772022-04-11 18:54:23 +000083 }
drh6fda1762022-04-16 23:38:29 +000084 } {1 11 111 1111 2 22 {} {} 3 33 {} {}}
danielk19773e8c37e2005-01-21 03:12:14 +000085}
drhb733d032004-01-24 20:18:12 +000086
danf112f0b2017-01-10 17:37:49 +000087#-------------------------------------------------------------------------
88# Check that ticket [25e335f802ddc] has been resolved. It should be an
89# error for the ON clause of a LEFT JOIN to refer to a table to its right.
90#
91do_execsql_test 2.0 {
92 CREATE TABLE aa(a);
93 CREATE TABLE bb(b);
94 CREATE TABLE cc(c);
95 INSERT INTO aa VALUES('one');
96 INSERT INTO bb VALUES('one');
97 INSERT INTO cc VALUES('one');
98}
99
100do_catchsql_test 2.1 {
drh25897872018-03-20 21:16:15 +0000101 SELECT * FROM aa LEFT JOIN cc ON (a=b) JOIN bb ON (b=coalesce(c,1));
danf112f0b2017-01-10 17:37:49 +0000102} {1 {ON clause references tables to its right}}
drhec270772022-04-11 18:54:23 +0000103do_catchsql_test 2.1b {
104 SELECT * FROM aa RIGHT JOIN cc ON (a=b) JOIN bb ON (b=coalesce(c,1));
105} {1 {ON clause references tables to its right}}
danf112f0b2017-01-10 17:37:49 +0000106do_catchsql_test 2.2 {
107 SELECT * FROM aa JOIN cc ON (a=b) JOIN bb ON (b=c);
108} {0 {one one one}}
109
dan75dbf682017-11-20 14:40:03 +0000110#-------------------------------------------------------------------------
111# Test that a problem causing where.c to overlook opportunities to
112# omit unnecessary tables from a LEFT JOIN when UNIQUE, NOT NULL column
113# that makes this possible happens to be the leftmost in its table.
114#
115reset_db
116do_execsql_test 3.0 {
117 CREATE TABLE t1(k1 INTEGER PRIMARY KEY, k2, k3);
118 CREATE TABLE t2(k2 INTEGER PRIMARY KEY, v2);
119
dan17f188e2017-11-20 15:45:03 +0000120 -- Prior to this problem being fixed, table t3_2 would be omitted from
121 -- the join queries below, but if t3_1 were used in its place it would
122 -- not.
dan75dbf682017-11-20 14:40:03 +0000123 CREATE TABLE t3_1(k3 PRIMARY KEY, v3) WITHOUT ROWID;
124 CREATE TABLE t3_2(v3, k3 PRIMARY KEY) WITHOUT ROWID;
125}
126
127do_eqp_test 3.1 {
128 SELECT v2 FROM t1 LEFT JOIN t2 USING (k2) LEFT JOIN t3_1 USING (k3);
129} {
drhb3f02762018-05-02 18:00:17 +0000130 QUERY PLAN
drh82102332021-03-20 15:11:29 +0000131 |--SCAN t1
drhc5837192022-04-11 14:26:37 +0000132 `--SEARCH t2 USING INTEGER PRIMARY KEY (rowid=?) LEFT-JOIN
dan75dbf682017-11-20 14:40:03 +0000133}
134
135do_eqp_test 3.2 {
136 SELECT v2 FROM t1 LEFT JOIN t2 USING (k2) LEFT JOIN t3_2 USING (k3);
137} {
drhb3f02762018-05-02 18:00:17 +0000138 QUERY PLAN
drh82102332021-03-20 15:11:29 +0000139 |--SCAN t1
drhc5837192022-04-11 14:26:37 +0000140 `--SEARCH t2 USING INTEGER PRIMARY KEY (rowid=?) LEFT-JOIN
dan75dbf682017-11-20 14:40:03 +0000141}
142
dan41203c62017-11-21 19:22:45 +0000143#-------------------------------------------------------------------------
144# Test that tables other than the rightmost can be omitted from a
145# LEFT JOIN query.
146#
147do_execsql_test 4.0 {
148 CREATE TABLE c1(k INTEGER PRIMARY KEY, v1);
149 CREATE TABLE c2(k INTEGER PRIMARY KEY, v2);
150 CREATE TABLE c3(k INTEGER PRIMARY KEY, v3);
151
152 INSERT INTO c1 VALUES(1, 2);
153 INSERT INTO c2 VALUES(2, 3);
154 INSERT INTO c3 VALUES(3, 'v3');
155
156 INSERT INTO c1 VALUES(111, 1112);
157 INSERT INTO c2 VALUES(112, 1113);
158 INSERT INTO c3 VALUES(113, 'v1113');
159}
160do_execsql_test 4.1.1 {
161 SELECT v1, v3 FROM c1 LEFT JOIN c2 ON (c2.k=v1) LEFT JOIN c3 ON (c3.k=v2);
162} {2 v3 1112 {}}
163do_execsql_test 4.1.2 {
164 SELECT v1, v3 FROM c1 LEFT JOIN c2 ON (c2.k=v1) LEFT JOIN c3 ON (c3.k=v1+1);
165} {2 v3 1112 {}}
166
167do_execsql_test 4.1.3 {
168 SELECT DISTINCT v1, v3 FROM c1 LEFT JOIN c2 LEFT JOIN c3 ON (c3.k=v1+1);
169} {2 v3 1112 {}}
170
171do_execsql_test 4.1.4 {
172 SELECT v1, v3 FROM c1 LEFT JOIN c2 LEFT JOIN c3 ON (c3.k=v1+1);
173} {2 v3 2 v3 1112 {} 1112 {}}
174
dan8433e712018-01-29 17:08:52 +0000175do_eqp_test 4.1.5 {
dan41203c62017-11-21 19:22:45 +0000176 SELECT v1, v3 FROM c1 LEFT JOIN c2 ON (c2.k=v1) LEFT JOIN c3 ON (c3.k=v2);
177} {
drhb3f02762018-05-02 18:00:17 +0000178 QUERY PLAN
drh82102332021-03-20 15:11:29 +0000179 |--SCAN c1
drhc5837192022-04-11 14:26:37 +0000180 |--SEARCH c2 USING INTEGER PRIMARY KEY (rowid=?) LEFT-JOIN
181 `--SEARCH c3 USING INTEGER PRIMARY KEY (rowid=?) LEFT-JOIN
dan41203c62017-11-21 19:22:45 +0000182}
dan8433e712018-01-29 17:08:52 +0000183do_eqp_test 4.1.6 {
dan41203c62017-11-21 19:22:45 +0000184 SELECT v1, v3 FROM c1 LEFT JOIN c2 ON (c2.k=v1) LEFT JOIN c3 ON (c3.k=v1+1);
185} {
drhb3f02762018-05-02 18:00:17 +0000186 QUERY PLAN
drh82102332021-03-20 15:11:29 +0000187 |--SCAN c1
drhc5837192022-04-11 14:26:37 +0000188 `--SEARCH c3 USING INTEGER PRIMARY KEY (rowid=?) LEFT-JOIN
dan41203c62017-11-21 19:22:45 +0000189}
190
dan8433e712018-01-29 17:08:52 +0000191do_execsql_test 4.2.0 {
192 DROP TABLE c1;
193 DROP TABLE c2;
194 DROP TABLE c3;
195 CREATE TABLE c1(k UNIQUE, v1);
196 CREATE TABLE c2(k UNIQUE, v2);
197 CREATE TABLE c3(k UNIQUE, v3);
198
199 INSERT INTO c1 VALUES(1, 2);
200 INSERT INTO c2 VALUES(2, 3);
201 INSERT INTO c3 VALUES(3, 'v3');
202
203 INSERT INTO c1 VALUES(111, 1112);
204 INSERT INTO c2 VALUES(112, 1113);
205 INSERT INTO c3 VALUES(113, 'v1113');
206}
207do_execsql_test 4.2.1 {
208 SELECT v1, v3 FROM c1 LEFT JOIN c2 ON (c2.k=v1) LEFT JOIN c3 ON (c3.k=v2);
209} {2 v3 1112 {}}
210do_execsql_test 4.2.2 {
211 SELECT v1, v3 FROM c1 LEFT JOIN c2 ON (c2.k=v1) LEFT JOIN c3 ON (c3.k=v1+1);
212} {2 v3 1112 {}}
213
214do_execsql_test 4.2.3 {
215 SELECT DISTINCT v1, v3 FROM c1 LEFT JOIN c2 LEFT JOIN c3 ON (c3.k=v1+1);
216} {2 v3 1112 {}}
217
218do_execsql_test 4.2.4 {
219 SELECT v1, v3 FROM c1 LEFT JOIN c2 LEFT JOIN c3 ON (c3.k=v1+1);
220} {2 v3 2 v3 1112 {} 1112 {}}
221
222do_eqp_test 4.2.5 {
223 SELECT v1, v3 FROM c1 LEFT JOIN c2 ON (c2.k=v1) LEFT JOIN c3 ON (c3.k=v2);
224} {
drhb3f02762018-05-02 18:00:17 +0000225 QUERY PLAN
drh82102332021-03-20 15:11:29 +0000226 |--SCAN c1
drhc5837192022-04-11 14:26:37 +0000227 |--SEARCH c2 USING INDEX sqlite_autoindex_c2_1 (k=?) LEFT-JOIN
228 `--SEARCH c3 USING INDEX sqlite_autoindex_c3_1 (k=?) LEFT-JOIN
dan8433e712018-01-29 17:08:52 +0000229}
230do_eqp_test 4.2.6 {
231 SELECT v1, v3 FROM c1 LEFT JOIN c2 ON (c2.k=v1) LEFT JOIN c3 ON (c3.k=v1+1);
232} {
drhb3f02762018-05-02 18:00:17 +0000233 QUERY PLAN
drh82102332021-03-20 15:11:29 +0000234 |--SCAN c1
drhc5837192022-04-11 14:26:37 +0000235 `--SEARCH c3 USING INDEX sqlite_autoindex_c3_1 (k=?) LEFT-JOIN
dan8433e712018-01-29 17:08:52 +0000236}
237
drh53bf7172017-11-23 04:45:35 +0000238# 2017-11-23 (Thanksgiving day)
239# OSSFuzz found an assertion fault in the new LEFT JOIN eliminator code.
240#
241do_execsql_test 4.3.0 {
242 DROP TABLE IF EXISTS t1;
243 DROP TABLE IF EXISTS t2;
244 CREATE TABLE t1(x PRIMARY KEY) WITHOUT ROWID;
245 CREATE TABLE t2(x);
246 SELECT a.x
247 FROM t1 AS a
248 LEFT JOIN t1 AS b ON (a.x=b.x)
249 LEFT JOIN t2 AS c ON (a.x=c.x);
250} {}
251do_execsql_test 4.3.1 {
252 WITH RECURSIVE c(x) AS (VALUES(1) UNION ALL SELECT x+1 FROM c WHERE x<10)
253 INSERT INTO t1(x) SELECT x FROM c;
254 INSERT INTO t2(x) SELECT x+9 FROM t1;
255 SELECT a.x, c.x
256 FROM t1 AS a
257 LEFT JOIN t1 AS b ON (a.x=b.x)
258 LEFT JOIN t2 AS c ON (a.x=c.x);
259} {1 {} 2 {} 3 {} 4 {} 5 {} 6 {} 7 {} 8 {} 9 {} 10 10}
dan41203c62017-11-21 19:22:45 +0000260
dan8433e712018-01-29 17:08:52 +0000261do_execsql_test 5.0 {
262 CREATE TABLE s1 (a INTEGER PRIMARY KEY);
263 CREATE TABLE s2 (a INTEGER PRIMARY KEY);
264 CREATE TABLE s3 (a INTEGER);
265 CREATE UNIQUE INDEX ndx on s3(a);
266}
267do_eqp_test 5.1 {
268 SELECT s1.a FROM s1 left join s2 using (a);
drh82102332021-03-20 15:11:29 +0000269} {SCAN s1}
drhb3f02762018-05-02 18:00:17 +0000270
dan8433e712018-01-29 17:08:52 +0000271do_eqp_test 5.2 {
272 SELECT s1.a FROM s1 left join s3 using (a);
drh82102332021-03-20 15:11:29 +0000273} {SCAN s1}
dan8433e712018-01-29 17:08:52 +0000274
dan4ea48142018-01-31 14:07:01 +0000275do_execsql_test 6.0 {
276 CREATE TABLE u1(a INTEGER PRIMARY KEY, b, c);
277 CREATE TABLE u2(a INTEGER PRIMARY KEY, b, c);
278 CREATE INDEX u1ab ON u1(b, c);
279}
280do_eqp_test 6.1 {
281 SELECT u2.* FROM u2 LEFT JOIN u1 ON( u1.a=u2.a AND u1.b=u2.b AND u1.c=u2.c );
drh82102332021-03-20 15:11:29 +0000282} {SCAN u2}
dan4ea48142018-01-31 14:07:01 +0000283
drh6a9b9522018-03-27 15:13:43 +0000284db close
285sqlite3 db :memory:
286do_execsql_test 7.0 {
287 CREATE TABLE t1(a,b); INSERT INTO t1 VALUES(1,2),(3,4),(5,6);
288 CREATE TABLE t2(c,d); INSERT INTO t2 VALUES(2,4),(3,6);
289 CREATE TABLE t3(x); INSERT INTO t3 VALUES(9);
290 CREATE VIEW test AS
291 SELECT *, 'x'
292 FROM t1 LEFT JOIN (SELECT * FROM t2, t3) ON (c=b AND x=9)
293 WHERE c IS NULL;
294 SELECT * FROM test;
295} {3 4 {} {} {} x 5 6 {} {} {} x}
296
dan1d24a532019-12-23 15:17:11 +0000297#-------------------------------------------------------------------------
298# Ticket [dfd66334].
299#
300reset_db
301do_execsql_test 8.0 {
302 CREATE TABLE t0(c0);
303 CREATE TABLE t1(c0);
304}
305
306do_execsql_test 8.1 {
307 SELECT * FROM t0 LEFT JOIN t1
308 WHERE (t1.c0 BETWEEN 0 AND 0) > ('' AND t0.c0);
309}
310
dan07f9e8f2020-04-25 15:01:53 +0000311#-------------------------------------------------------------------------
drh46fe1382020-08-19 23:32:06 +0000312# Ticket [45f4bf4eb] reported by Manuel Rigger (2020-04-25)
313#
314# Follow up error reported by Eric Speckman on the SQLite forum
315# https://sqlite.org/forum/info/c49496d24d35bd7c (2020-08-19)
dan07f9e8f2020-04-25 15:01:53 +0000316#
317reset_db
318do_execsql_test 9.0 {
319 CREATE TABLE t0(c0 INT);
320 CREATE VIEW v0(c0) AS SELECT CAST(t0.c0 AS INTEGER) FROM t0;
321 INSERT INTO t0(c0) VALUES (0);
322}
323
324do_execsql_test 9.1 {
325 SELECT typeof(c0), c0 FROM v0 WHERE c0>='0'
326} {integer 0}
327
328do_execsql_test 9.2 {
329 SELECT * FROM t0, v0 WHERE v0.c0 >= '0';
330} {0 0}
331
332do_execsql_test 9.3 {
333 SELECT * FROM t0 LEFT JOIN v0 WHERE v0.c0 >= '0';
334} {0 0}
335
336do_execsql_test 9.4 {
337 SELECT * FROM t0 LEFT JOIN v0 ON v0.c0 >= '0';
338} {0 0}
339
340do_execsql_test 9.5 {
341 SELECT * FROM t0 LEFT JOIN v0 ON v0.c0 >= '0' WHERE TRUE
342 UNION SELECT 0,0 WHERE 0;
343} {0 0}
344
drh46fe1382020-08-19 23:32:06 +0000345do_execsql_test 9.10 {
346 CREATE TABLE t1 (aaa);
347 INSERT INTO t1 VALUES(23456);
348 CREATE TABLE t2(bbb);
349 CREATE VIEW v2(ccc) AS SELECT bbb IS 1234 FROM t2;
350 SELECT ccc, ccc IS NULL AS ddd FROM t1 LEFT JOIN v2;
351} {{} 1}
352optimization_control db query-flattener 0
353do_execsql_test 9.11 {
354 SELECT ccc, ccc IS NULL AS ddd FROM t1 LEFT JOIN v2;
355} {{} 1}
356
drh6a9b9522018-03-27 15:13:43 +0000357
drhb733d032004-01-24 20:18:12 +0000358finish_test