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 #***********************************************************************
11 # This file implements regression tests for SQLite library.
13 # This file implements tests for joins, including outer joins.
16 set testdir [file dirname $argv0]
17 source $testdir/tester.tcl
23 INSERT INTO t1 VALUES(1,11);
24 INSERT INTO t1 VALUES(2,22);
25 INSERT INTO t1 VALUES(3,33);
32 INSERT INTO t2 VALUES(11,111);
33 INSERT INTO t2 VALUES(33,333);
34 INSERT INTO t2 VALUES(44,444);
37 } {11 111 33 333 44 444};
41 INSERT INTO t3 VALUES(111,1111);
42 INSERT INTO t3 VALUES(444,4444);
43 INSERT INTO t3 VALUES(555,5555);
46 } {111 1111 444 4444 555 5555}
51 t1 NATURAL JOIN t2 NATURAL JOIN t3
57 t1 NATURAL JOIN t2 NATURAL LEFT OUTER JOIN t3
59 } {1 11 111 1111 3 33 333 {}}
63 t1 NATURAL LEFT OUTER JOIN t2 NATURAL JOIN t3
70 t1 NATURAL LEFT OUTER JOIN (t2 NATURAL JOIN t3)
72 } {1 11 111 1111 2 22 {} {} 3 33 {} {}}
75 #-------------------------------------------------------------------------
76 # Check that ticket [25e335f802ddc] has been resolved. It should be an
77 # error for the ON clause of a LEFT JOIN to refer to a table to its right.
83 INSERT INTO aa VALUES('one');
84 INSERT INTO bb VALUES('one');
85 INSERT INTO cc VALUES('one');
88 do_catchsql_test 2.1 {
89 SELECT * FROM aa LEFT JOIN cc ON (a=b) JOIN bb ON (b=coalesce(c,1));
90 } {1 {ON clause references tables to its right}}
91 do_catchsql_test 2.2 {
92 SELECT * FROM aa JOIN cc ON (a=b) JOIN bb ON (b=c);
95 #-------------------------------------------------------------------------
96 # Test that a problem causing where.c to overlook opportunities to
97 # omit unnecessary tables from a LEFT JOIN when UNIQUE, NOT NULL column
98 # that makes this possible happens to be the leftmost in its table.
101 do_execsql_test 3.0 {
102 CREATE TABLE t1(k1 INTEGER PRIMARY KEY, k2, k3);
103 CREATE TABLE t2(k2 INTEGER PRIMARY KEY, v2);
105 -- Prior to this problem being fixed, table t3_2 would be omitted from
106 -- the join queries below, but if t3_1 were used in its place it would
108 CREATE TABLE t3_1(k3 PRIMARY KEY, v3) WITHOUT ROWID;
109 CREATE TABLE t3_2(v3, k3 PRIMARY KEY) WITHOUT ROWID;
113 SELECT v2 FROM t1 LEFT JOIN t2 USING (k2) LEFT JOIN t3_1 USING (k3);
115 0 0 0 {SCAN TABLE t1}
116 0 1 1 {SEARCH TABLE t2 USING INTEGER PRIMARY KEY (rowid=?)}
120 SELECT v2 FROM t1 LEFT JOIN t2 USING (k2) LEFT JOIN t3_2 USING (k3);
122 0 0 0 {SCAN TABLE t1}
123 0 1 1 {SEARCH TABLE t2 USING INTEGER PRIMARY KEY (rowid=?)}
126 #-------------------------------------------------------------------------
127 # Test that tables other than the rightmost can be omitted from a
130 do_execsql_test 4.0 {
131 CREATE TABLE c1(k INTEGER PRIMARY KEY, v1);
132 CREATE TABLE c2(k INTEGER PRIMARY KEY, v2);
133 CREATE TABLE c3(k INTEGER PRIMARY KEY, v3);
135 INSERT INTO c1 VALUES(1, 2);
136 INSERT INTO c2 VALUES(2, 3);
137 INSERT INTO c3 VALUES(3, 'v3');
139 INSERT INTO c1 VALUES(111, 1112);
140 INSERT INTO c2 VALUES(112, 1113);
141 INSERT INTO c3 VALUES(113, 'v1113');
143 do_execsql_test 4.1.1 {
144 SELECT v1, v3 FROM c1 LEFT JOIN c2 ON (c2.k=v1) LEFT JOIN c3 ON (c3.k=v2);
146 do_execsql_test 4.1.2 {
147 SELECT v1, v3 FROM c1 LEFT JOIN c2 ON (c2.k=v1) LEFT JOIN c3 ON (c3.k=v1+1);
150 do_execsql_test 4.1.3 {
151 SELECT DISTINCT v1, v3 FROM c1 LEFT JOIN c2 LEFT JOIN c3 ON (c3.k=v1+1);
154 do_execsql_test 4.1.4 {
155 SELECT v1, v3 FROM c1 LEFT JOIN c2 LEFT JOIN c3 ON (c3.k=v1+1);
156 } {2 v3 2 v3 1112 {} 1112 {}}
159 SELECT v1, v3 FROM c1 LEFT JOIN c2 ON (c2.k=v1) LEFT JOIN c3 ON (c3.k=v2);
161 0 0 0 {SCAN TABLE c1}
162 0 1 1 {SEARCH TABLE c2 USING INTEGER PRIMARY KEY (rowid=?)}
163 0 2 2 {SEARCH TABLE c3 USING INTEGER PRIMARY KEY (rowid=?)}
166 SELECT v1, v3 FROM c1 LEFT JOIN c2 ON (c2.k=v1) LEFT JOIN c3 ON (c3.k=v1+1);
168 0 0 0 {SCAN TABLE c1}
169 0 1 2 {SEARCH TABLE c3 USING INTEGER PRIMARY KEY (rowid=?)}
172 do_execsql_test 4.2.0 {
176 CREATE TABLE c1(k UNIQUE, v1);
177 CREATE TABLE c2(k UNIQUE, v2);
178 CREATE TABLE c3(k UNIQUE, v3);
180 INSERT INTO c1 VALUES(1, 2);
181 INSERT INTO c2 VALUES(2, 3);
182 INSERT INTO c3 VALUES(3, 'v3');
184 INSERT INTO c1 VALUES(111, 1112);
185 INSERT INTO c2 VALUES(112, 1113);
186 INSERT INTO c3 VALUES(113, 'v1113');
188 do_execsql_test 4.2.1 {
189 SELECT v1, v3 FROM c1 LEFT JOIN c2 ON (c2.k=v1) LEFT JOIN c3 ON (c3.k=v2);
191 do_execsql_test 4.2.2 {
192 SELECT v1, v3 FROM c1 LEFT JOIN c2 ON (c2.k=v1) LEFT JOIN c3 ON (c3.k=v1+1);
195 do_execsql_test 4.2.3 {
196 SELECT DISTINCT v1, v3 FROM c1 LEFT JOIN c2 LEFT JOIN c3 ON (c3.k=v1+1);
199 do_execsql_test 4.2.4 {
200 SELECT v1, v3 FROM c1 LEFT JOIN c2 LEFT JOIN c3 ON (c3.k=v1+1);
201 } {2 v3 2 v3 1112 {} 1112 {}}
204 SELECT v1, v3 FROM c1 LEFT JOIN c2 ON (c2.k=v1) LEFT JOIN c3 ON (c3.k=v2);
206 0 0 0 {SCAN TABLE c1}
207 0 1 1 {SEARCH TABLE c2 USING INDEX sqlite_autoindex_c2_1 (k=?)}
208 0 2 2 {SEARCH TABLE c3 USING INDEX sqlite_autoindex_c3_1 (k=?)}
211 SELECT v1, v3 FROM c1 LEFT JOIN c2 ON (c2.k=v1) LEFT JOIN c3 ON (c3.k=v1+1);
213 0 0 0 {SCAN TABLE c1}
214 0 1 2 {SEARCH TABLE c3 USING INDEX sqlite_autoindex_c3_1 (k=?)}
217 # 2017-11-23 (Thanksgiving day)
218 # OSSFuzz found an assertion fault in the new LEFT JOIN eliminator code.
220 do_execsql_test 4.3.0 {
221 DROP TABLE IF EXISTS t1;
222 DROP TABLE IF EXISTS t2;
223 CREATE TABLE t1(x PRIMARY KEY) WITHOUT ROWID;
227 LEFT JOIN t1 AS b ON (a.x=b.x)
228 LEFT JOIN t2 AS c ON (a.x=c.x);
230 do_execsql_test 4.3.1 {
231 WITH RECURSIVE c(x) AS (VALUES(1) UNION ALL SELECT x+1 FROM c WHERE x<10)
232 INSERT INTO t1(x) SELECT x FROM c;
233 INSERT INTO t2(x) SELECT x+9 FROM t1;
236 LEFT JOIN t1 AS b ON (a.x=b.x)
237 LEFT JOIN t2 AS c ON (a.x=c.x);
238 } {1 {} 2 {} 3 {} 4 {} 5 {} 6 {} 7 {} 8 {} 9 {} 10 10}
240 do_execsql_test 5.0 {
241 CREATE TABLE s1 (a INTEGER PRIMARY KEY);
242 CREATE TABLE s2 (a INTEGER PRIMARY KEY);
243 CREATE TABLE s3 (a INTEGER);
244 CREATE UNIQUE INDEX ndx on s3(a);
247 SELECT s1.a FROM s1 left join s2 using (a);
249 0 0 0 {SCAN TABLE s1}
252 SELECT s1.a FROM s1 left join s3 using (a);
254 0 0 0 {SCAN TABLE s1}
257 do_execsql_test 6.0 {
258 CREATE TABLE u1(a INTEGER PRIMARY KEY, b, c);
259 CREATE TABLE u2(a INTEGER PRIMARY KEY, b, c);
260 CREATE INDEX u1ab ON u1(b, c);
263 SELECT u2.* FROM u2 LEFT JOIN u1 ON( u1.a=u2.a AND u1.b=u2.b AND u1.c=u2.c );
265 0 0 0 {SCAN TABLE u2}
270 do_execsql_test 7.0 {
271 CREATE TABLE t1(a,b); INSERT INTO t1 VALUES(1,2),(3,4),(5,6);
272 CREATE TABLE t2(c,d); INSERT INTO t2 VALUES(2,4),(3,6);
273 CREATE TABLE t3(x); INSERT INTO t3 VALUES(9);
276 FROM t1 LEFT JOIN (SELECT * FROM t2, t3) ON (c=b AND x=9)
279 } {3 4 {} {} {} x 5 6 {} {} {} x}