000001 # 2002-05-24
000002 #
000003 # The author disclaims copyright to this source code. In place of
000004 # a legal notice, here is a blessing:
000005 #
000006 # May you do good and not evil.
000007 # May you find forgiveness for yourself and forgive others.
000008 # May you share freely, never taking more than you give.
000009 #
000010 #***********************************************************************
000011 # This file implements regression tests for SQLite library.
000012 #
000013 # This file implements tests for joins, including outer joins.
000014 #
000015
000016 set testdir [file dirname $argv0]
000017 source $testdir/tester.tcl
000018
000019 do_test join-1.1 {
000020 execsql {
000021 CREATE TABLE t1(a,b,c);
000022 INSERT INTO t1 VALUES(1,2,3);
000023 INSERT INTO t1 VALUES(2,3,4);
000024 INSERT INTO t1 VALUES(3,4,5);
000025 SELECT * FROM t1;
000026 }
000027 } {1 2 3 2 3 4 3 4 5}
000028 do_test join-1.2 {
000029 execsql {
000030 CREATE TABLE t2(b,c,d);
000031 INSERT INTO t2 VALUES(1,2,3);
000032 INSERT INTO t2 VALUES(2,3,4);
000033 INSERT INTO t2 VALUES(3,4,5);
000034 SELECT * FROM t2;
000035 }
000036 } {1 2 3 2 3 4 3 4 5}
000037
000038 # A FROM clause of the form: "<table>, <table> ON <expr>" is not
000039 # allowed by the SQLite syntax diagram, nor by any other SQL database
000040 # engine that we are aware of. Nevertheless, historic versions of
000041 # SQLite have allowed it. We need to continue to support it moving
000042 # forward to prevent breakage of legacy applications. Though, we will
000043 # not advertise it as being supported.
000044 #
000045 do_execsql_test join-1.2.1 {
000046 SELECT t1.rowid, t2.rowid, '|' FROM t1, t2 ON t1.a=t2.b;
000047 } {1 1 | 2 2 | 3 3 |}
000048
000049 do_test join-1.3 {
000050 execsql2 {
000051 SELECT * FROM t1 NATURAL JOIN t2;
000052 }
000053 } {a 1 b 2 c 3 d 4 a 2 b 3 c 4 d 5}
000054 do_test join-1.3.1 {
000055 execsql2 {
000056 SELECT * FROM t2 NATURAL JOIN t1;
000057 }
000058 } {b 2 c 3 d 4 a 1 b 3 c 4 d 5 a 2}
000059 do_test join-1.3.2 {
000060 execsql2 {
000061 SELECT * FROM t2 AS x NATURAL JOIN t1;
000062 }
000063 } {b 2 c 3 d 4 a 1 b 3 c 4 d 5 a 2}
000064 do_test join-1.3.3 {
000065 execsql2 {
000066 SELECT * FROM t2 NATURAL JOIN t1 AS y;
000067 }
000068 } {b 2 c 3 d 4 a 1 b 3 c 4 d 5 a 2}
000069 do_test join-1.3.4 {
000070 execsql {
000071 SELECT b FROM t1 NATURAL JOIN t2;
000072 }
000073 } {2 3}
000074
000075 # ticket #3522
000076 do_test join-1.3.5 {
000077 execsql2 {
000078 SELECT t2.* FROM t2 NATURAL JOIN t1
000079 }
000080 } {b 2 c 3 d 4 b 3 c 4 d 5}
000081 do_test join-1.3.6 {
000082 execsql2 {
000083 SELECT xyzzy.* FROM t2 AS xyzzy NATURAL JOIN t1
000084 }
000085 } {b 2 c 3 d 4 b 3 c 4 d 5}
000086 do_test join-1.3.7 {
000087 execsql2 {
000088 SELECT t1.* FROM t2 NATURAL JOIN t1
000089 }
000090 } {a 1 b 2 c 3 a 2 b 3 c 4}
000091 do_test join-1.3.8 {
000092 execsql2 {
000093 SELECT xyzzy.* FROM t2 NATURAL JOIN t1 AS xyzzy
000094 }
000095 } {a 1 b 2 c 3 a 2 b 3 c 4}
000096 do_test join-1.3.9 {
000097 execsql2 {
000098 SELECT aaa.*, bbb.* FROM t2 AS aaa NATURAL JOIN t1 AS bbb
000099 }
000100 } {b 2 c 3 d 4 a 1 b 2 c 3 b 3 c 4 d 5 a 2 b 3 c 4}
000101 do_test join-1.3.10 {
000102 execsql2 {
000103 SELECT t1.*, t2.* FROM t2 NATURAL JOIN t1
000104 }
000105 } {a 1 b 2 c 3 b 2 c 3 d 4 a 2 b 3 c 4 b 3 c 4 d 5}
000106
000107
000108 do_test join-1.4.1 {
000109 execsql2 {
000110 SELECT * FROM t1 INNER JOIN t2 USING(b,c);
000111 }
000112 } {a 1 b 2 c 3 d 4 a 2 b 3 c 4 d 5}
000113 do_test join-1.4.2 {
000114 execsql2 {
000115 SELECT * FROM t1 AS x INNER JOIN t2 USING(b,c);
000116 }
000117 } {a 1 b 2 c 3 d 4 a 2 b 3 c 4 d 5}
000118 do_test join-1.4.3 {
000119 execsql2 {
000120 SELECT * FROM t1 INNER JOIN t2 AS y USING(b,c);
000121 }
000122 } {a 1 b 2 c 3 d 4 a 2 b 3 c 4 d 5}
000123 do_test join-1.4.4 {
000124 execsql2 {
000125 SELECT * FROM t1 AS x INNER JOIN t2 AS y USING(b,c);
000126 }
000127 } {a 1 b 2 c 3 d 4 a 2 b 3 c 4 d 5}
000128 do_test join-1.4.5 {
000129 execsql {
000130 SELECT b FROM t1 JOIN t2 USING(b);
000131 }
000132 } {2 3}
000133
000134 # Ticket #3522
000135 do_test join-1.4.6 {
000136 execsql2 {
000137 SELECT t1.* FROM t1 JOIN t2 USING(b);
000138 }
000139 } {a 1 b 2 c 3 a 2 b 3 c 4}
000140 do_test join-1.4.7 {
000141 execsql2 {
000142 SELECT t2.* FROM t1 JOIN t2 USING(b);
000143 }
000144 } {b 2 c 3 d 4 b 3 c 4 d 5}
000145
000146 do_test join-1.5 {
000147 execsql2 {
000148 SELECT * FROM t1 INNER JOIN t2 USING(b);
000149 }
000150 } {a 1 b 2 c 3 c 3 d 4 a 2 b 3 c 4 c 4 d 5}
000151 do_test join-1.6 {
000152 execsql2 {
000153 SELECT * FROM t1 INNER JOIN t2 USING(c);
000154 }
000155 } {a 1 b 2 c 3 b 2 d 4 a 2 b 3 c 4 b 3 d 5}
000156 do_test join-1.7 {
000157 execsql2 {
000158 SELECT * FROM t1 INNER JOIN t2 USING(c,b);
000159 }
000160 } {a 1 b 2 c 3 d 4 a 2 b 3 c 4 d 5}
000161
000162 do_test join-1.8 {
000163 execsql {
000164 SELECT * FROM t1 NATURAL CROSS JOIN t2;
000165 }
000166 } {1 2 3 4 2 3 4 5}
000167 do_test join-1.9 {
000168 execsql {
000169 SELECT * FROM t1 CROSS JOIN t2 USING(b,c);
000170 }
000171 } {1 2 3 4 2 3 4 5}
000172 do_test join-1.10 {
000173 execsql {
000174 SELECT * FROM t1 NATURAL INNER JOIN t2;
000175 }
000176 } {1 2 3 4 2 3 4 5}
000177 do_test join-1.11 {
000178 execsql {
000179 SELECT * FROM t1 INNER JOIN t2 USING(b,c);
000180 }
000181 } {1 2 3 4 2 3 4 5}
000182 do_test join-1.12 {
000183 execsql {
000184 SELECT * FROM t1 natural inner join t2;
000185 }
000186 } {1 2 3 4 2 3 4 5}
000187
000188 ifcapable subquery {
000189 do_test join-1.13 {
000190 execsql2 {
000191 SELECT * FROM t1 NATURAL JOIN
000192 (SELECT b as 'c', c as 'd', d as 'e' FROM t2) as t3
000193 }
000194 } {a 1 b 2 c 3 d 4 e 5}
000195 do_test join-1.14 {
000196 execsql2 {
000197 SELECT * FROM (SELECT b as 'c', c as 'd', d as 'e' FROM t2) as 'tx'
000198 NATURAL JOIN t1
000199 }
000200 } {c 3 d 4 e 5 a 1 b 2}
000201 }
000202
000203 do_test join-1.15 {
000204 execsql {
000205 CREATE TABLE t3(c,d,e);
000206 INSERT INTO t3 VALUES(2,3,4);
000207 INSERT INTO t3 VALUES(3,4,5);
000208 INSERT INTO t3 VALUES(4,5,6);
000209 SELECT * FROM t3;
000210 }
000211 } {2 3 4 3 4 5 4 5 6}
000212 do_test join-1.16 {
000213 execsql {
000214 SELECT * FROM t1 natural join t2 natural join t3;
000215 }
000216 } {1 2 3 4 5 2 3 4 5 6}
000217 do_test join-1.17 {
000218 execsql2 {
000219 SELECT * FROM t1 natural join t2 natural join t3;
000220 }
000221 } {a 1 b 2 c 3 d 4 e 5 a 2 b 3 c 4 d 5 e 6}
000222 do_test join-1.18 {
000223 execsql {
000224 CREATE TABLE t4(d,e,f);
000225 INSERT INTO t4 VALUES(2,3,4);
000226 INSERT INTO t4 VALUES(3,4,5);
000227 INSERT INTO t4 VALUES(4,5,6);
000228 SELECT * FROM t4;
000229 }
000230 } {2 3 4 3 4 5 4 5 6}
000231 do_test join-1.19.1 {
000232 execsql {
000233 SELECT * FROM t1 natural join t2 natural join t4;
000234 }
000235 } {1 2 3 4 5 6}
000236 do_test join-1.19.2 {
000237 execsql2 {
000238 SELECT * FROM t1 natural join t2 natural join t4;
000239 }
000240 } {a 1 b 2 c 3 d 4 e 5 f 6}
000241 do_test join-1.20 {
000242 execsql {
000243 SELECT * FROM t1 natural join t2 natural join t3 WHERE t1.a=1
000244 }
000245 } {1 2 3 4 5}
000246
000247 do_test join-2.1 {
000248 execsql {
000249 SELECT * FROM t1 NATURAL LEFT JOIN t2;
000250 }
000251 } {1 2 3 4 2 3 4 5 3 4 5 {}}
000252
000253 # EVIDENCE-OF: R-52129-05406 you can say things like "OUTER LEFT NATURAL
000254 # JOIN" which means the same as "NATURAL LEFT OUTER JOIN".
000255 do_test join-2.1b {
000256 execsql {
000257 SELECT * FROM t1 OUTER LEFT NATURAL JOIN t2;
000258 }
000259 } {1 2 3 4 2 3 4 5 3 4 5 {}}
000260 do_test join-2.1c {
000261 execsql {
000262 SELECT * FROM t1 NATURAL LEFT OUTER JOIN t2;
000263 }
000264 } {1 2 3 4 2 3 4 5 3 4 5 {}}
000265
000266 # ticket #3522
000267 do_test join-2.1.1 {
000268 execsql2 {
000269 SELECT * FROM t1 NATURAL LEFT JOIN t2;
000270 }
000271 } {a 1 b 2 c 3 d 4 a 2 b 3 c 4 d 5 a 3 b 4 c 5 d {}}
000272 do_test join-2.1.2 {
000273 execsql2 {
000274 SELECT t1.* FROM t1 NATURAL LEFT JOIN t2;
000275 }
000276 } {a 1 b 2 c 3 a 2 b 3 c 4 a 3 b 4 c 5}
000277 do_test join-2.1.3 {
000278 execsql2 {
000279 SELECT t2.* FROM t1 NATURAL LEFT JOIN t2;
000280 }
000281 } {b 2 c 3 d 4 b 3 c 4 d 5 b {} c {} d {}}
000282
000283 do_test join-2.2 {
000284 execsql {
000285 SELECT * FROM t2 NATURAL LEFT OUTER JOIN t1;
000286 }
000287 } {1 2 3 {} 2 3 4 1 3 4 5 2}
000288
000289 #do_test join-2.3 {
000290 # catchsql {
000291 # SELECT * FROM t1 NATURAL RIGHT OUTER JOIN t2;
000292 # }
000293 #} {1 {RIGHT and FULL OUTER JOINs are not currently supported}}
000294
000295 do_test join-2.4 {
000296 execsql {
000297 SELECT * FROM t1 LEFT JOIN t2 ON t1.a=t2.d
000298 }
000299 } {1 2 3 {} {} {} 2 3 4 {} {} {} 3 4 5 1 2 3}
000300 do_test join-2.5 {
000301 execsql {
000302 SELECT * FROM t1 LEFT JOIN t2 ON t1.a=t2.d WHERE t1.a>1
000303 }
000304 } {2 3 4 {} {} {} 3 4 5 1 2 3}
000305 do_test join-2.6 {
000306 execsql {
000307 SELECT * FROM t1 LEFT JOIN t2 ON t1.a=t2.d WHERE t2.b IS NULL OR t2.b>1
000308 }
000309 } {1 2 3 {} {} {} 2 3 4 {} {} {}}
000310
000311 do_test join-3.1 {
000312 catchsql {
000313 SELECT * FROM t1 NATURAL JOIN t2 ON t1.a=t2.b;
000314 }
000315 } {1 {a NATURAL join may not have an ON or USING clause}}
000316 do_test join-3.2 {
000317 catchsql {
000318 SELECT * FROM t1 NATURAL JOIN t2 USING(b);
000319 }
000320 } {1 {a NATURAL join may not have an ON or USING clause}}
000321 do_test join-3.3 {
000322 catchsql {
000323 SELECT * FROM t1 JOIN t2 ON t1.a=t2.b USING(b);
000324 }
000325 } {1 {near "USING": syntax error}}
000326 do_test join-3.4.1 {
000327 catchsql {
000328 SELECT * FROM t1 JOIN t2 USING(a);
000329 }
000330 } {1 {cannot join using column a - column not present in both tables}}
000331 do_test join-3.4.2 {
000332 catchsql {
000333 SELECT * FROM t1 JOIN t2 USING(d);
000334 }
000335 } {1 {cannot join using column d - column not present in both tables}}
000336 do_test join-3.5 {
000337 catchsql { SELECT * FROM t1 USING(a) }
000338 } {1 {a JOIN clause is required before USING}}
000339 do_test join-3.6 {
000340 catchsql {
000341 SELECT * FROM t1 JOIN t2 ON t3.a=t2.b;
000342 }
000343 } {1 {no such column: t3.a}}
000344
000345 # EVIDENCE-OF: R-47973-48020 you cannot say "INNER OUTER JOIN", because
000346 # that would be contradictory.
000347 do_test join-3.7 {
000348 catchsql {
000349 SELECT * FROM t1 INNER OUTER JOIN t2;
000350 }
000351 } {1 {unknown join type: INNER OUTER}}
000352 do_test join-3.8 {
000353 catchsql {
000354 SELECT * FROM t1 INNER OUTER CROSS JOIN t2;
000355 }
000356 } {1 {unknown join type: INNER OUTER CROSS}}
000357 do_test join-3.9 {
000358 catchsql {
000359 SELECT * FROM t1 OUTER NATURAL INNER JOIN t2;
000360 }
000361 } {1 {unknown join type: OUTER NATURAL INNER}}
000362 do_test join-3.10 {
000363 catchsql {
000364 SELECT * FROM t1 LEFT BOGUS JOIN t2;
000365 }
000366 } {1 {unknown join type: LEFT BOGUS}}
000367 do_test join-3.11 {
000368 catchsql {
000369 SELECT * FROM t1 INNER BOGUS CROSS JOIN t2;
000370 }
000371 } {1 {unknown join type: INNER BOGUS CROSS}}
000372 do_test join-3.12 {
000373 catchsql {
000374 SELECT * FROM t1 NATURAL AWK SED JOIN t2;
000375 }
000376 } {1 {unknown join type: NATURAL AWK SED}}
000377
000378 do_test join-4.1 {
000379 execsql {
000380 BEGIN;
000381 CREATE TABLE t5(a INTEGER PRIMARY KEY);
000382 CREATE TABLE t6(a INTEGER);
000383 INSERT INTO t6 VALUES(NULL);
000384 INSERT INTO t6 VALUES(NULL);
000385 INSERT INTO t6 SELECT * FROM t6;
000386 INSERT INTO t6 SELECT * FROM t6;
000387 INSERT INTO t6 SELECT * FROM t6;
000388 INSERT INTO t6 SELECT * FROM t6;
000389 INSERT INTO t6 SELECT * FROM t6;
000390 INSERT INTO t6 SELECT * FROM t6;
000391 COMMIT;
000392 }
000393 execsql {
000394 SELECT * FROM t6 NATURAL JOIN t5;
000395 }
000396 } {}
000397 do_test join-4.2 {
000398 execsql {
000399 SELECT * FROM t6, t5 WHERE t6.a<t5.a;
000400 }
000401 } {}
000402 do_test join-4.3 {
000403 execsql {
000404 SELECT * FROM t6, t5 WHERE t6.a>t5.a;
000405 }
000406 } {}
000407 do_test join-4.4 {
000408 execsql {
000409 UPDATE t6 SET a='xyz';
000410 SELECT * FROM t6 NATURAL JOIN t5;
000411 }
000412 } {}
000413 do_test join-4.6 {
000414 execsql {
000415 SELECT * FROM t6, t5 WHERE t6.a<t5.a;
000416 }
000417 } {}
000418 do_test join-4.7 {
000419 execsql {
000420 SELECT * FROM t6, t5 WHERE t6.a>t5.a;
000421 }
000422 } {}
000423 do_test join-4.8 {
000424 execsql {
000425 UPDATE t6 SET a=1;
000426 SELECT * FROM t6 NATURAL JOIN t5;
000427 }
000428 } {}
000429 do_test join-4.9 {
000430 execsql {
000431 SELECT * FROM t6, t5 WHERE t6.a<t5.a;
000432 }
000433 } {}
000434 do_test join-4.10 {
000435 execsql {
000436 SELECT * FROM t6, t5 WHERE t6.a>t5.a;
000437 }
000438 } {}
000439
000440 do_test join-5.1 {
000441 execsql {
000442 BEGIN;
000443 create table centros (id integer primary key, centro);
000444 INSERT INTO centros VALUES(1,'xxx');
000445 create table usuarios (id integer primary key, nombre, apellidos,
000446 idcentro integer);
000447 INSERT INTO usuarios VALUES(1,'a','aa',1);
000448 INSERT INTO usuarios VALUES(2,'b','bb',1);
000449 INSERT INTO usuarios VALUES(3,'c','cc',NULL);
000450 create index idcentro on usuarios (idcentro);
000451 END;
000452 select usuarios.id, usuarios.nombre, centros.centro from
000453 usuarios left outer join centros on usuarios.idcentro = centros.id;
000454 }
000455 } {1 a xxx 2 b xxx 3 c {}}
000456
000457 # A test for ticket #247.
000458 #
000459 do_test join-7.1 {
000460 sqlite3_db_config db SQLITE_DBCONFIG_DQS_DML 1
000461 execsql {
000462 CREATE TABLE t7 (x, y);
000463 INSERT INTO t7 VALUES ("pa1", 1);
000464 INSERT INTO t7 VALUES ("pa2", NULL);
000465 INSERT INTO t7 VALUES ("pa3", NULL);
000466 INSERT INTO t7 VALUES ("pa4", 2);
000467 INSERT INTO t7 VALUES ("pa30", 131);
000468 INSERT INTO t7 VALUES ("pa31", 130);
000469 INSERT INTO t7 VALUES ("pa28", NULL);
000470
000471 CREATE TABLE t8 (a integer primary key, b);
000472 INSERT INTO t8 VALUES (1, "pa1");
000473 INSERT INTO t8 VALUES (2, "pa4");
000474 INSERT INTO t8 VALUES (3, NULL);
000475 INSERT INTO t8 VALUES (4, NULL);
000476 INSERT INTO t8 VALUES (130, "pa31");
000477 INSERT INTO t8 VALUES (131, "pa30");
000478
000479 SELECT coalesce(t8.a,999) from t7 LEFT JOIN t8 on y=a;
000480 }
000481 } {1 999 999 2 131 130 999}
000482
000483 # Make sure a left join where the right table is really a view that
000484 # is itself a join works right. Ticket #306.
000485 #
000486 ifcapable view {
000487 do_test join-8.1 {
000488 execsql {
000489 BEGIN;
000490 CREATE TABLE t9(a INTEGER PRIMARY KEY, b);
000491 INSERT INTO t9 VALUES(1,11);
000492 INSERT INTO t9 VALUES(2,22);
000493 CREATE TABLE t10(x INTEGER PRIMARY KEY, y);
000494 INSERT INTO t10 VALUES(1,2);
000495 INSERT INTO t10 VALUES(3,3);
000496 CREATE TABLE t11(p INTEGER PRIMARY KEY, q);
000497 INSERT INTO t11 VALUES(2,111);
000498 INSERT INTO t11 VALUES(3,333);
000499 CREATE VIEW v10_11 AS SELECT x, q FROM t10, t11 WHERE t10.y=t11.p;
000500 COMMIT;
000501 SELECT * FROM t9 LEFT JOIN v10_11 ON( a=x );
000502 }
000503 } {1 11 1 111 2 22 {} {}}
000504 ifcapable subquery {
000505 do_test join-8.2 {
000506 execsql {
000507 SELECT * FROM t9 LEFT JOIN (SELECT x, q FROM t10, t11 WHERE t10.y=t11.p)
000508 ON( a=x);
000509 }
000510 } {1 11 1 111 2 22 {} {}}
000511 }
000512 do_test join-8.3 {
000513 execsql {
000514 SELECT * FROM v10_11 LEFT JOIN t9 ON( a=x );
000515 }
000516 } {1 111 1 11 3 333 {} {}}
000517 ifcapable subquery {
000518 # Constant expressions in a subquery that is the right element of a
000519 # LEFT JOIN evaluate to NULL for rows where the LEFT JOIN does not
000520 # match. Ticket #3300
000521 do_test join-8.4 {
000522 execsql {
000523 SELECT * FROM t9 LEFT JOIN (SELECT 44, p, q FROM t11) AS sub1 ON p=a
000524 }
000525 } {1 11 {} {} {} 2 22 44 2 111}
000526 }
000527 } ;# ifcapable view
000528
000529 # Ticket #350 describes a scenario where LEFT OUTER JOIN does not
000530 # function correctly if the right table in the join is really
000531 # subquery.
000532 #
000533 # To test the problem, we generate the same LEFT OUTER JOIN in two
000534 # separate selects but with on using a subquery and the other calling
000535 # the table directly. Then connect the two SELECTs using an EXCEPT.
000536 # Both queries should generate the same results so the answer should
000537 # be an empty set.
000538 #
000539 ifcapable compound {
000540 do_test join-9.1 {
000541 execsql {
000542 BEGIN;
000543 CREATE TABLE t12(a,b);
000544 INSERT INTO t12 VALUES(1,11);
000545 INSERT INTO t12 VALUES(2,22);
000546 CREATE TABLE t13(b,c);
000547 INSERT INTO t13 VALUES(22,222);
000548 COMMIT;
000549 }
000550 } {}
000551
000552 ifcapable subquery {
000553 do_test join-9.1.1 {
000554 execsql {
000555 SELECT * FROM t12 NATURAL LEFT JOIN t13
000556 EXCEPT
000557 SELECT * FROM t12 NATURAL LEFT JOIN (SELECT * FROM t13 WHERE b>0);
000558 }
000559 } {}
000560 }
000561 ifcapable view {
000562 do_test join-9.2 {
000563 execsql {
000564 CREATE VIEW v13 AS SELECT * FROM t13 WHERE b>0;
000565 SELECT * FROM t12 NATURAL LEFT JOIN t13
000566 EXCEPT
000567 SELECT * FROM t12 NATURAL LEFT JOIN v13;
000568 }
000569 } {}
000570 } ;# ifcapable view
000571 } ;# ifcapable compound
000572
000573 ifcapable subquery {
000574 # Ticket #1697: Left Join WHERE clause terms that contain an
000575 # aggregate subquery.
000576 #
000577 do_test join-10.1 {
000578 execsql {
000579 CREATE TABLE t21(a,b,c);
000580 CREATE TABLE t22(p,q);
000581 CREATE INDEX i22 ON t22(q);
000582 SELECT a FROM t21 LEFT JOIN t22 ON b=p WHERE q=
000583 (SELECT max(m.q) FROM t22 m JOIN t21 n ON n.b=m.p WHERE n.c=1);
000584 }
000585 } {}
000586
000587 # Test a LEFT JOIN when the right-hand side of hte join is an empty
000588 # sub-query. Seems fine.
000589 #
000590 do_test join-10.2 {
000591 execsql {
000592 CREATE TABLE t23(a, b, c);
000593 CREATE TABLE t24(a, b, c);
000594 INSERT INTO t23 VALUES(1, 2, 3);
000595 }
000596 execsql {
000597 SELECT * FROM t23 LEFT JOIN t24;
000598 }
000599 } {1 2 3 {} {} {}}
000600 do_test join-10.3 {
000601 execsql {
000602 SELECT * FROM t23 LEFT JOIN (SELECT * FROM t24);
000603 }
000604 } {1 2 3 {} {} {}}
000605
000606 } ;# ifcapable subquery
000607
000608 #-------------------------------------------------------------------------
000609 # The following tests are to ensure that bug b73fb0bd64 is fixed.
000610 #
000611 do_test join-11.1 {
000612 drop_all_tables
000613 execsql {
000614 CREATE TABLE t1(a INTEGER PRIMARY KEY, b TEXT);
000615 CREATE TABLE t2(a INTEGER PRIMARY KEY, b TEXT);
000616 INSERT INTO t1 VALUES(1,'abc');
000617 INSERT INTO t1 VALUES(2,'def');
000618 INSERT INTO t2 VALUES(1,'abc');
000619 INSERT INTO t2 VALUES(2,'def');
000620 SELECT * FROM t1 NATURAL JOIN t2;
000621 }
000622 } {1 abc 2 def}
000623
000624 do_test join-11.2 {
000625 execsql { SELECT a FROM t1 JOIN t1 USING (a)}
000626 } {1 2}
000627 do_test join-11.3 {
000628 execsql { SELECT a FROM t1 JOIN t1 AS t2 USING (a)}
000629 } {1 2}
000630 do_test join-11.3 {
000631 execsql { SELECT * FROM t1 NATURAL JOIN t1 AS t2}
000632 } {1 abc 2 def}
000633 do_test join-11.4 {
000634 execsql { SELECT * FROM t1 NATURAL JOIN t1 }
000635 } {1 abc 2 def}
000636
000637 do_test join-11.5 {
000638 drop_all_tables
000639 execsql {
000640 CREATE TABLE t1(a COLLATE nocase, b);
000641 CREATE TABLE t2(a, b);
000642 INSERT INTO t1 VALUES('ONE', 1);
000643 INSERT INTO t1 VALUES('two', 2);
000644 INSERT INTO t2 VALUES('one', 1);
000645 INSERT INTO t2 VALUES('two', 2);
000646 }
000647 } {}
000648 do_test join-11.6 {
000649 execsql { SELECT * FROM t1 NATURAL JOIN t2 }
000650 } {ONE 1 two 2}
000651 do_test join-11.7 {
000652 execsql { SELECT * FROM t2 NATURAL JOIN t1 }
000653 } {two 2}
000654
000655 do_test join-11.8 {
000656 drop_all_tables
000657 execsql {
000658 CREATE TABLE t1(a, b TEXT);
000659 CREATE TABLE t2(b INTEGER, a);
000660 INSERT INTO t1 VALUES('one', '1.0');
000661 INSERT INTO t1 VALUES('two', '2');
000662 INSERT INTO t2 VALUES(1, 'one');
000663 INSERT INTO t2 VALUES(2, 'two');
000664 }
000665 } {}
000666 do_test join-11.9 {
000667 execsql { SELECT * FROM t1 NATURAL JOIN t2 }
000668 } {one 1.0 two 2}
000669 do_test join-11.10 {
000670 execsql { SELECT * FROM t2 NATURAL JOIN t1 }
000671 } {1 one 2 two}
000672
000673 #-------------------------------------------------------------------------
000674 # Test that at most 64 tables are allowed in a join.
000675 #
000676 do_execsql_test join-12.1 {
000677 CREATE TABLE t14(x);
000678 INSERT INTO t14 VALUES('abcdefghij');
000679 }
000680
000681 proc jointest {tn nTbl res} {
000682 set sql "SELECT 1 FROM [string repeat t14, [expr $nTbl-1]] t14;"
000683 uplevel [list do_catchsql_test $tn $sql $res]
000684 }
000685
000686 jointest join-12.2 30 {0 1}
000687 jointest join-12.3 63 {0 1}
000688 jointest join-12.4 64 {0 1}
000689 jointest join-12.5 65 {1 {at most 64 tables in a join}}
000690 jointest join-12.6 66 {1 {at most 64 tables in a join}}
000691 jointest join-12.7 127 {1 {at most 64 tables in a join}}
000692 jointest join-12.8 128 {1 {at most 64 tables in a join}}
000693
000694 # As of 2019-01-17, the number of elements in a SrcList is limited
000695 # to 200. The following tests still run, but the answer is now
000696 # an SQLITE_NOMEM error.
000697 #
000698 # jointest join-12.9 1000 {1 {at most 64 tables in a join}}
000699 #
000700 # If SQLite is built with SQLITE_MEMDEBUG, then the huge number of realloc()
000701 # calls made by the following test cases are too time consuming to run.
000702 # Without SQLITE_MEMDEBUG, realloc() is fast enough that these are not
000703 # a problem.
000704 #
000705 # ifcapable pragma&&compileoption_diags {
000706 # if {[lsearch [db eval {PRAGMA compile_options}] MEMDEBUG]<0} {
000707 # jointest join-12.10 65534 {1 {at most 64 tables in a join}}
000708 # jointest join-12.11 65535 {1 {too many references to "t14": max 65535}}
000709 # jointest join-12.12 65536 {1 {too many references to "t14": max 65535}}
000710 # jointest join-12.13 65537 {1 {too many references to "t14": max 65535}}
000711 # }
000712 # }
000713
000714
000715 #-------------------------------------------------------------------------
000716 # Test a problem with reordering tables following a LEFT JOIN.
000717 #
000718 do_execsql_test join-13.0 {
000719 CREATE TABLE aa(a);
000720 CREATE TABLE bb(b);
000721 CREATE TABLE cc(c);
000722
000723 INSERT INTO aa VALUES(45);
000724 INSERT INTO cc VALUES(45);
000725 INSERT INTO cc VALUES(45);
000726 }
000727
000728 do_execsql_test join-13.1 {
000729 SELECT * FROM aa LEFT JOIN bb, cc WHERE cc.c=aa.a;
000730 } {45 {} 45 45 {} 45}
000731
000732 # In the following, the order of [cc] and [bb] must not be exchanged, even
000733 # though this would be helpful if the query used an inner join.
000734 do_execsql_test join-13.2 {
000735 CREATE INDEX ccc ON cc(c);
000736 SELECT * FROM aa LEFT JOIN bb, cc WHERE cc.c=aa.a;
000737 } {45 {} 45 45 {} 45}
000738
000739 # Verify that that iTable attributes the TK_IF_NULL_ROW operators in the
000740 # expression tree are correctly updated by the query flattener. This was
000741 # a bug discovered on 2017-05-22 by Mark Brand.
000742 #
000743 do_execsql_test join-14.1 {
000744 SELECT *
000745 FROM (SELECT 1 a) AS x
000746 LEFT JOIN (SELECT 1, * FROM (SELECT * FROM (SELECT 1)));
000747 } {1 1 1}
000748 do_execsql_test join-14.2 {
000749 SELECT *
000750 FROM (SELECT 1 a) AS x
000751 LEFT JOIN (SELECT 1, * FROM (SELECT * FROM (SELECT * FROM (SELECT 1)))) AS y
000752 JOIN (SELECT * FROM (SELECT 9)) AS z;
000753 } {1 1 1 9}
000754 do_execsql_test join-14.3 {
000755 SELECT *
000756 FROM (SELECT 111)
000757 LEFT JOIN (SELECT cc+222, * FROM (SELECT * FROM (SELECT 333 cc)));
000758 } {111 555 333}
000759
000760 do_execsql_test join-14.4 {
000761 DROP TABLE IF EXISTS t1;
000762 CREATE TABLE t1(c PRIMARY KEY, a TEXT(10000), b TEXT(10000));
000763 SELECT * FROM (SELECT 111) LEFT JOIN (SELECT c+222 FROM t1) GROUP BY 1;
000764 } {111 {}}
000765 do_execsql_test join-14.4b {
000766 SELECT * FROM (SELECT 111) LEFT JOIN (SELECT c+222 FROM t1);
000767 } {111 {}}
000768 do_execsql_test join-14.5 {
000769 SELECT * FROM (SELECT 111 AS x UNION ALL SELECT 222)
000770 LEFT JOIN (SELECT c+333 AS y FROM t1) ON x=y GROUP BY 1;
000771 } {111 {} 222 {}}
000772 do_execsql_test join-14.5b {
000773 SELECT count(*)
000774 FROM (SELECT 111 AS x UNION ALL SELECT 222)
000775 LEFT JOIN (SELECT c+333 AS y FROM t1) ON x=y;
000776 } {2}
000777 do_execsql_test join-14.5c {
000778 SELECT count(*)
000779 FROM (SELECT c+333 AS y FROM t1)
000780 RIGHT JOIN (SELECT 111 AS x UNION ALL SELECT 222) ON x=y;
000781 } {2}
000782 do_execsql_test join-14.6 {
000783 SELECT * FROM (SELECT 111 AS x UNION ALL SELECT 111)
000784 LEFT JOIN (SELECT c+333 AS y FROM t1) ON x=y GROUP BY 1;
000785 } {111 {}}
000786 do_execsql_test join-14.7 {
000787 SELECT * FROM (SELECT 111 AS x UNION ALL SELECT 111 UNION ALL SELECT 222)
000788 LEFT JOIN (SELECT c+333 AS y FROM t1) ON x=y GROUP BY 1;
000789 } {111 {} 222 {}}
000790 do_execsql_test join-14.8 {
000791 INSERT INTO t1(c) VALUES(-111);
000792 SELECT * FROM (SELECT 111 AS x UNION ALL SELECT 111 UNION ALL SELECT 222)
000793 LEFT JOIN (SELECT c+333 AS y FROM t1) ON x=y GROUP BY 1;
000794 } {111 {} 222 222}
000795 do_execsql_test join-14.9 {
000796 DROP TABLE IF EXISTS t1;
000797 CREATE TABLE t1(c PRIMARY KEY) WITHOUT ROWID;
000798 SELECT * FROM (SELECT 111) LEFT JOIN (SELECT c+222 FROM t1) GROUP BY 1;
000799 } {111 {}}
000800
000801 # Verify the fix to ticket
000802 # https://www.sqlite.org/src/tktview/7fde638e94287d2c948cd9389
000803 #
000804 db close
000805 sqlite3 db :memory:
000806 do_execsql_test join-14.10 {
000807 CREATE TABLE t1(a);
000808 INSERT INTO t1 VALUES(1),(2),(3);
000809 CREATE VIEW v2 AS SELECT a, 1 AS b FROM t1;
000810 CREATE TABLE t3(x);
000811 INSERT INTO t3 VALUES(2),(4);
000812 SELECT *, '|' FROM t3 LEFT JOIN v2 ON a=x WHERE b=1;
000813 } {2 2 1 |}
000814 do_execsql_test join-14.11 {
000815 SELECT *, '|' FROM t3 LEFT JOIN v2 ON a=x WHERE b+1=x;
000816 } {2 2 1 |}
000817 do_execsql_test join-14.12 {
000818 SELECT *, '|' FROM t3 LEFT JOIN v2 ON a=x ORDER BY b;
000819 } {4 {} {} | 2 2 1 |}
000820
000821 # Verify the fix for ticket
000822 # https://www.sqlite.org/src/info/892fc34f173e99d8
000823 #
000824 db close
000825 sqlite3 db :memory:
000826 do_execsql_test join-14.20 {
000827 CREATE TABLE t1(id INTEGER PRIMARY KEY);
000828 CREATE TABLE t2(id INTEGER PRIMARY KEY, c2 INTEGER);
000829 CREATE TABLE t3(id INTEGER PRIMARY KEY, c3 INTEGER);
000830 INSERT INTO t1(id) VALUES(456);
000831 INSERT INTO t3(id) VALUES(1),(2);
000832 SELECT t1.id, x2.id, x3.id
000833 FROM t1
000834 LEFT JOIN (SELECT * FROM t2) AS x2 ON t1.id=x2.c2
000835 LEFT JOIN t3 AS x3 ON x2.id=x3.c3;
000836 } {456 {} {}}
000837
000838 # 2018-03-24.
000839 # E.Pasma discovered that the LEFT JOIN strength reduction optimization
000840 # was misbehaving. The problem turned out to be that the
000841 # sqlite3ExprImpliesNotNull() routine was saying that CASE expressions
000842 # like
000843 #
000844 # CASE WHEN true THEN true ELSE x=0 END
000845 #
000846 # could never be true if x is NULL. The following test cases verify
000847 # that this error has been resolved.
000848 #
000849 db close
000850 sqlite3 db :memory:
000851 do_execsql_test join-15.100 {
000852 CREATE TABLE t1(a INT, b INT);
000853 INSERT INTO t1 VALUES(1,2),(3,4);
000854 CREATE TABLE t2(x INT, y INT);
000855 SELECT *, 'x'
000856 FROM t1 LEFT JOIN t2
000857 WHERE CASE WHEN FALSE THEN a=x ELSE 1 END;
000858 } {1 2 {} {} x 3 4 {} {} x}
000859 do_execsql_test join-15.105 {
000860 SELECT *, 'x'
000861 FROM t1 LEFT JOIN t2
000862 WHERE a IN (1,3,x,y);
000863 } {1 2 {} {} x 3 4 {} {} x}
000864 do_execsql_test join-15.106a {
000865 SELECT *, 'x'
000866 FROM t1 LEFT JOIN t2
000867 WHERE NOT ( 'x'='y' AND t2.y=1 );
000868 } {1 2 {} {} x 3 4 {} {} x}
000869 do_execsql_test join-15.106b {
000870 SELECT *, 'x'
000871 FROM t1 LEFT JOIN t2
000872 WHERE ~ ( 'x'='y' AND t2.y=1 );
000873 } {1 2 {} {} x 3 4 {} {} x}
000874 do_execsql_test join-15.107 {
000875 SELECT *, 'x'
000876 FROM t1 LEFT JOIN t2
000877 WHERE t2.y IS NOT 'abc'
000878 } {1 2 {} {} x 3 4 {} {} x}
000879 do_execsql_test join-15.110 {
000880 DROP TABLE t1;
000881 DROP TABLE t2;
000882 CREATE TABLE t1(a INTEGER PRIMARY KEY, b INTEGER);
000883 INSERT INTO t1(a,b) VALUES(1,0),(11,1),(12,1),(13,1),(121,12);
000884 CREATE INDEX t1b ON t1(b);
000885 CREATE TABLE t2(x INTEGER PRIMARY KEY);
000886 INSERT INTO t2(x) VALUES(0),(1);
000887 SELECT a1, a2, a3, a4, a5
000888 FROM (SELECT a AS a1 FROM t1 WHERE b=0)
000889 JOIN (SELECT x AS x1 FROM t2)
000890 LEFT JOIN (SELECT a AS a2, b AS b2 FROM t1)
000891 ON x1 IS TRUE AND b2=a1
000892 JOIN (SELECT x AS x2 FROM t2)
000893 ON x2<=CASE WHEN x1 THEN CASE WHEN a2 THEN 1 ELSE -1 END ELSE 0 END
000894 LEFT JOIN (SELECT a AS a3, b AS b3 FROM t1)
000895 ON x2 IS TRUE AND b3=a2
000896 JOIN (SELECT x AS x3 FROM t2)
000897 ON x3<=CASE WHEN x2 THEN CASE WHEN a3 THEN 1 ELSE -1 END ELSE 0 END
000898 LEFT JOIN (SELECT a AS a4, b AS b4 FROM t1)
000899 ON x3 IS TRUE AND b4=a3
000900 JOIN (SELECT x AS x4 FROM t2)
000901 ON x4<=CASE WHEN x3 THEN CASE WHEN a4 THEN 1 ELSE -1 END ELSE 0 END
000902 LEFT JOIN (SELECT a AS a5, b AS b5 FROM t1)
000903 ON x4 IS TRUE AND b5=a4
000904 ORDER BY a1, a2, a3, a4, a5;
000905 } {1 {} {} {} {} 1 11 {} {} {} 1 12 {} {} {} 1 12 121 {} {} 1 13 {} {} {}}
000906
000907 # 2019-02-05 Ticket https://www.sqlite.org/src/tktview/5948e09b8c415bc45da5c
000908 # Error in join due to the LEFT JOIN strength reduction optimization.
000909 #
000910 do_execsql_test join-16.100 {
000911 DROP TABLE IF EXISTS t1;
000912 DROP TABLE IF EXISTS t2;
000913 CREATE TABLE t1(a INT);
000914 INSERT INTO t1(a) VALUES(1);
000915 CREATE TABLE t2(b INT);
000916 SELECT a, b
000917 FROM t1 LEFT JOIN t2 ON 0
000918 WHERE (b IS NOT NULL)=0;
000919 } {1 {}}
000920
000921 # 2019-08-17 ticket https://sqlite.org/src/tktview/6710d2f7a13a299728ab
000922 # Ensure that constants that derive from the right-hand table of a LEFT JOIN
000923 # are never factored out, since they are not really constant.
000924 #
000925 do_execsql_test join-17.100 {
000926 DROP TABLE IF EXISTS t1;
000927 CREATE TABLE t1(x);
000928 INSERT INTO t1(x) VALUES(0),(1);
000929 SELECT * FROM t1 LEFT JOIN (SELECT abs(1) AS y FROM t1) ON x WHERE NOT(y='a');
000930 } {1 1 1 1}
000931 do_execsql_test join-17.110 {
000932 SELECT * FROM t1 LEFT JOIN (SELECT abs(1)+2 AS y FROM t1) ON x
000933 WHERE NOT(y='a');
000934 } {1 3 1 3}
000935
000936 #-------------------------------------------------------------------------
000937 reset_db
000938 do_execsql_test join-18.1 {
000939 CREATE TABLE t0(a);
000940 CREATE TABLE t1(b);
000941 CREATE VIEW v0 AS SELECT a FROM t1 LEFT JOIN t0;
000942 INSERT INTO t1 VALUES (1);
000943 } {}
000944
000945 do_execsql_test join-18.2 {
000946 SELECT * FROM v0 WHERE NOT(v0.a IS FALSE);
000947 } {{}}
000948
000949 do_execsql_test join-18.3 {
000950 SELECT * FROM t1 LEFT JOIN t0 WHERE NOT(a IS FALSE);
000951 } {1 {}}
000952
000953 do_execsql_test join-18.4 {
000954 SELECT NOT(v0.a IS FALSE) FROM v0
000955 } {1}
000956
000957 #-------------------------------------------------------------------------
000958 reset_db
000959 do_execsql_test join-19.0 {
000960 CREATE TABLE t1(a);
000961 CREATE TABLE t2(b);
000962 INSERT INTO t1(a) VALUES(0);
000963 CREATE VIEW v0(c) AS SELECT t2.b FROM t1 LEFT JOIN t2;
000964 }
000965
000966 do_execsql_test join-19.1 {
000967 SELECT * FROM v0 WHERE v0.c NOTNULL NOTNULL;
000968 } {{}}
000969
000970 do_execsql_test join-19.2 {
000971 SELECT * FROM t1 LEFT JOIN t2
000972 } {0 {}}
000973
000974 do_execsql_test join-19.3 {
000975 SELECT * FROM t1 LEFT JOIN t2 WHERE (b IS NOT NULL) IS NOT NULL;
000976 } {0 {}}
000977
000978 do_execsql_test join-19.4 {
000979 SELECT (b IS NOT NULL) IS NOT NULL FROM t1 LEFT JOIN t2
000980 } {1}
000981
000982 do_execsql_test join-19.5 {
000983 SELECT * FROM t1 LEFT JOIN t2 WHERE
000984 (b IS NOT NULL AND b IS NOT NULL) IS NOT NULL;
000985 } {0 {}}
000986
000987 # 2019-11-02 ticket 623eff57e76d45f6
000988 # The optimization of exclusing the WHERE expression of a partial index
000989 # from the WHERE clause of the query if the index is used does not work
000990 # of the table of the index is the right-hand table of a LEFT JOIN.
000991 #
000992 db close
000993 sqlite3 db :memory:
000994 do_execsql_test join-20.1 {
000995 CREATE TABLE t1(c1);
000996 CREATE TABLE t0(c0);
000997 INSERT INTO t0(c0) VALUES (0);
000998 SELECT * FROM t0 LEFT JOIN t1 WHERE NULL IN (c1);
000999 } {}
001000 do_execsql_test join-20.2 {
001001 CREATE INDEX t1x ON t1(0) WHERE NULL IN (c1);
001002 SELECT * FROM t0 LEFT JOIN t1 WHERE NULL IN (c1);
001003 } {}
001004
001005 # 2019-11-30 ticket 7f39060a24b47353
001006 # Do not allow a WHERE clause term to qualify a partial index on the
001007 # right table of a LEFT JOIN.
001008 #
001009 do_execsql_test join-21.10 {
001010 DROP TABLE t0;
001011 DROP TABLE t1;
001012 CREATE TABLE t0(aa);
001013 CREATE TABLE t1(bb);
001014 INSERT INTO t0(aa) VALUES (1);
001015 INSERT INTO t1(bb) VALUES (1);
001016 SELECT 11, * FROM t1 LEFT JOIN t0 WHERE aa ISNULL;
001017 SELECT 12, * FROM t1 LEFT JOIN t0 WHERE +aa ISNULL;
001018 SELECT 13, * FROM t1 LEFT JOIN t0 ON aa ISNULL;
001019 SELECT 14, * FROM t1 LEFT JOIN t0 ON +aa ISNULL;
001020 CREATE INDEX i0 ON t0(aa) WHERE aa ISNULL;
001021 SELECT 21, * FROM t1 LEFT JOIN t0 WHERE aa ISNULL;
001022 SELECT 22, * FROM t1 LEFT JOIN t0 WHERE +aa ISNULL;
001023 SELECT 23, * FROM t1 LEFT JOIN t0 ON aa ISNULL;
001024 SELECT 24, * FROM t1 LEFT JOIN t0 ON +aa ISNULL;
001025 } {13 1 {} 14 1 {} 23 1 {} 24 1 {}}
001026
001027 # 2019-12-18 problem with a LEFT JOIN where the RHS is a view.
001028 # Detected by Yongheng and Rui.
001029 # Follows from the optimization attempt of check-in 41c27bc0ff1d3135
001030 # on 2017-04-18
001031 #
001032 reset_db
001033 do_execsql_test join-22.10 {
001034 CREATE TABLE t0(a, b);
001035 CREATE INDEX t0a ON t0(a);
001036 INSERT INTO t0 VALUES(10,10),(10,11),(10,12);
001037 SELECT DISTINCT c FROM t0 LEFT JOIN (SELECT a+1 AS c FROM t0) ORDER BY c ;
001038 } {11}
001039
001040 # 2019-12-22 ticket 7929c1efb2d67e98
001041 # Verification of testtag-20230227a
001042 #
001043 # 2023-02-27 https://sqlite.org/forum/forumpost/422e635f3beafbf6
001044 # Verification of testtag-20230227a, testtag-20230227b, and testtag-20230227c
001045 #
001046 reset_db
001047 ifcapable vtab {
001048 do_execsql_test join-23.10 {
001049 CREATE TABLE t0(c0);
001050 INSERT INTO t0(c0) VALUES(123);
001051 CREATE VIEW v0(c0) AS SELECT 0 GROUP BY 1;
001052 SELECT t0.c0, v0.c0, vt0.name
001053 FROM v0, t0 LEFT JOIN pragma_table_info('t0') AS vt0
001054 ON vt0.name LIKE 'c0'
001055 WHERE v0.c0 == 0;
001056 } {123 0 c0}
001057 do_execsql_test join-23.20 {
001058 CREATE TABLE a(value TEXT);
001059 INSERT INTO a(value) SELECT value FROM json_each('["a", "b", null]');
001060 CREATE TABLE b(value TEXT);
001061 INSERT INTO b(value) SELECT value FROM json_each('["a", "c", null]');
001062 SELECT a.value, b.value FROM a RIGHT JOIN b ON a.value = b.value;
001063 } {a a {} c {} {}}
001064 do_execsql_test join-23.21 {
001065 SELECT a.value, b.value FROM b LEFT JOIN a ON a.value = b.value;
001066 } {a a {} c {} {}}
001067 do_execsql_test join-23.22 {
001068 SELECT a.value, b.value
001069 FROM json_each('["a", "c", null]') AS b
001070 LEFT JOIN
001071 json_each('["a", "b", null]') AS a ON a.value = b.value;
001072 } {a a {} c {} {}}
001073 do_execsql_test join-23.23 {
001074 SELECT a.value, b.value
001075 FROM json_each('["a", "b", null]') AS a
001076 RIGHT JOIN
001077 json_each('["a", "c", null]') AS b ON a.value = b.value;
001078 } {a a {} c {} {}}
001079 do_execsql_test join-23.24 {
001080 SELECT a.value, b.value
001081 FROM json_each('["a", "b", null]') AS a
001082 RIGHT JOIN
001083 b ON a.value = b.value;
001084 } {a a {} c {} {}}
001085 do_execsql_test join-23.25 {
001086 SELECT a.value, b.value
001087 FROM a
001088 RIGHT JOIN
001089 json_each('["a", "c", null]') AS b ON a.value = b.value;
001090 } {a a {} c {} {}}
001091 }
001092
001093 #-------------------------------------------------------------------------
001094 reset_db
001095 do_execsql_test join-24.1 {
001096 CREATE TABLE t1(a PRIMARY KEY, x);
001097 CREATE TABLE t2(b INT);
001098 CREATE INDEX t1aa ON t1(a, a);
001099
001100 INSERT INTO t1 VALUES('abc', 'def');
001101 INSERT INTO t2 VALUES(1);
001102 }
001103
001104 do_execsql_test join-24.2 {
001105 SELECT * FROM t2 JOIN t1 WHERE a='abc' AND x='def';
001106 } {1 abc def}
001107 do_execsql_test join-24.3 {
001108 SELECT * FROM t2 JOIN t1 WHERE a='abc' AND x='abc';
001109 } {}
001110
001111 do_execsql_test join-24.2 {
001112 SELECT * FROM t2 LEFT JOIN t1 ON a=0 WHERE (x='x' OR x IS NULL);
001113 } {1 {} {}}
001114
001115 # 2020-09-30 ticket 66e4b0e271c47145
001116 # The query flattener inserts an "expr AND expr" expression as a substitution
001117 # for the column of a view where that view column is part of an ON expression
001118 # of a LEFT JOIN.
001119 #
001120 reset_db
001121 do_execsql_test join-25.1 {
001122 CREATE TABLE t0(c0 INT);
001123 CREATE VIEW v0 AS SELECT (NULL AND 5) as c0 FROM t0;
001124 INSERT INTO t0(c0) VALUES (NULL);
001125 SELECT count(*) FROM v0 LEFT JOIN t0 ON v0.c0;
001126 } {1}
001127
001128 # 2022-04-21 Parser issue detected by dbsqlfuzz
001129 #
001130 reset_db
001131 do_catchsql_test join-26.1 {
001132 CREATE TABLE t4(a,b);
001133 CREATE TABLE t5(a,c);
001134 CREATE TABLE t6(a,d);
001135 SELECT * FROM t5 JOIN ((t4 JOIN (t5 JOIN t6)) t7);
001136 } {/1 {.*}/}
001137
001138 # 2022-06-09 Invalid subquery flattening caused by
001139 # check-in 3f45007d544e5f78 and detected by dbsqlfuzz
001140 #
001141 reset_db
001142 do_execsql_test join-27.1 {
001143 CREATE TABLE t1(a INT,b INT,c INT); INSERT INTO t1 VALUES(NULL,NULL,NULL);
001144 CREATE TABLE t2(d INT,e INT); INSERT INTO t2 VALUES(NULL,NULL);
001145 CREATE INDEX x2 ON t1(c,b);
001146 CREATE TABLE t3(x INT); INSERT INTO t3 VALUES(NULL);
001147 }
001148 do_execsql_test join-27.2 {
001149 WITH t99(b) AS MATERIALIZED (
001150 SELECT b FROM t2 LEFT JOIN t1 ON c IN (SELECT x FROM t3)
001151 )
001152 SELECT 5 FROM t2 JOIN t99 ON b IN (1,2,3);
001153 } {}
001154 do_execsql_test join-27.3 {
001155 WITH t99(b) AS NOT MATERIALIZED (
001156 SELECT b FROM t2 LEFT JOIN t1 ON c IN (SELECT x FROM t3)
001157 )
001158 SELECT 5 FROM t2 JOIN t99 ON b IN (1,2,3);
001159 } {}
001160 do_execsql_test join-27.4 {
001161 WITH t99(b) AS (SELECT b FROM t2 LEFT JOIN t1 ON c IN (SELECT x FROM t3))
001162 SELECT 5 FROM t2 JOIN t99 ON b IN (1,2,3);
001163 } {}
001164 do_execsql_test join-27.5 {
001165 SELECT 5
001166 FROM t2 JOIN (
001167 SELECT b FROM t2 LEFT JOIN t1 ON c IN (SELECT x FROM t3)
001168 ) AS t99 ON b IN (1,2,3);
001169 } {}
001170
001171 db null NULL
001172 do_execsql_test join-27.6 {
001173 INSERT INTO t1 VALUES(3,4,NULL);
001174 INSERT INTO t2 VALUES(1,2);
001175 WITH t99(b) AS (
001176 SELECT coalesce(b,3) FROM t2 AS x LEFT JOIN t1 ON c IN (SELECT x FROM t3)
001177 )
001178 SELECT d, e, b FROM t2 JOIN t99 ON b IN (1,2,3) ORDER BY +d;
001179 } {NULL NULL 3 NULL NULL 3 1 2 3 1 2 3}
001180 do_execsql_test join-27.7 {
001181 SELECT d, e, b2
001182 FROM t2
001183 JOIN (SELECT coalesce(b,3) AS b2 FROM t2 AS x LEFT JOIN t1
001184 ON c IN (SELECT x FROM t3)) AS t99
001185 ON b2 IN (1,2,3) ORDER BY +d;
001186 } {NULL NULL 3 NULL NULL 3 1 2 3 1 2 3}
001187
001188 do_execsql_test join-27.8 {
001189 DELETE FROM t1;
001190 DELETE FROM t2 WHERE d IS NOT NULL;
001191 DELETE FROM t3;
001192 SELECT * FROM t2 JOIN (SELECT b FROM t2 LEFT JOIN t1
001193 ON c IN (SELECT x FROM t3)) AS t99 ON b IN (1,2,3);
001194 } {}
001195
001196 do_execsql_test join-27.9 {
001197 DELETE FROM t1;
001198 DELETE FROM t2;
001199 DELETE FROM t3;
001200 INSERT INTO t1 VALUES(4,3,5);
001201 INSERT INTO t2 VALUES(1,2);
001202 INSERT INTO t3 VALUES(5);
001203 SELECT * FROM t2 JOIN (SELECT b FROM t2 LEFT JOIN t1
001204 ON c IN (SELECT x FROM t3)) AS t99 ON b IS NULL;
001205 } {}
001206 do_execsql_test join-27.10 {
001207 WITH t99(b) AS (
001208 SELECT b FROM t2 AS x LEFT JOIN t1 ON c IN (SELECT x FROM t3)
001209 )
001210 SELECT d, e, b FROM t2 JOIN t99 ON b IS NULL;
001211 } {}
001212
001213
001214 # 2022-09-19 https://sqlite.org/forum/forumpost/96b9e5709cf47cda
001215 # Performance regression relative to version 3.38.0 that resulted from
001216 # a new query flattener restriction that was added to fixes the join-27.*
001217 # tests above. The restriction needed to be removed and the join-27.*
001218 # problem fixed another way.
001219 #
001220 reset_db
001221 do_execsql_test join-28.1 {
001222 CREATE TABLE t1(a INTEGER PRIMARY KEY, b INT, c INT);
001223 CREATE TABLE t2(d INTEGER PRIMARY KEY, e INT);
001224 CREATE VIEW t3(a,b,c,d,e) AS SELECT * FROM t1 LEFT JOIN t2 ON d=c;
001225 CREATE TABLE t4(x INT, y INT);
001226 INSERT INTO t1 VALUES(1,2,3);
001227 INSERT INTO t2 VALUES(1,5);
001228 INSERT INTO t4 VALUES(1,4);
001229 SELECT a, b, y FROM t4 JOIN t3 ON a=x;
001230 } {1 2 4}
001231 do_eqp_test join-28.2 {
001232 SELECT a, b, y FROM t4 JOIN t3 ON a=x;
001233 } {
001234 QUERY PLAN
001235 |--SCAN t4
001236 `--SEARCH t1 USING INTEGER PRIMARY KEY (rowid=?)
001237 }
001238 # ^^^^^^^ Without the fix (if the query flattening optimization does not
001239 # run) the query plan above would look like this:
001240 #
001241 # QUERY PLAN
001242 # |--MATERIALIZE t3
001243 # | |--SCAN t1
001244 # | `--SEARCH t2 USING INTEGER PRIMARY KEY (rowid=?) LEFT-JOIN
001245 # |--SCAN t4
001246 # `--SEARCH t3 USING AUTOMATIC COVERING INDEX (a=?)
001247
001248
001249 # 2023-05-01 https://sqlite.org/forum/forumpost/96cd4a7e9e
001250 #
001251 reset_db
001252 db null NULL
001253 do_execsql_test join-29.1 {
001254 CREATE TABLE t0(a INT); INSERT INTO t0(a) VALUES (1);
001255 CREATE TABLE t1(b INT); INSERT INTO t1(b) VALUES (2);
001256 CREATE VIEW v2(c) AS SELECT 3 FROM t1;
001257 SELECT * FROM t1 JOIN v2 ON 0 FULL OUTER JOIN t0 ON true;
001258 } {NULL NULL 1}
001259 do_execsql_test join-29.2 {
001260 SELECT * FROM t1 JOIN v2 ON 1=0 FULL OUTER JOIN t0 ON true;
001261 } {NULL NULL 1}
001262 do_execsql_test join-29.3 {
001263 SELECT * FROM t1 JOIN v2 ON false FULL OUTER JOIN t0 ON true;
001264 } {NULL NULL 1}
001265
001266 # 2023-05-11 https://sqlite.org/forum/forumpost/49f2c7f690
001267 # Verify that omit-noop-join optimization does not apply if the table
001268 # to be omitted has an inner-join constraint and there is a RIGHT JOIN
001269 # anywhere in the query.
001270 #
001271 reset_db
001272 db null NULL
001273 do_execsql_test join-30.1 {
001274 CREATE TABLE t0(z INT); INSERT INTO t0 VALUES(1),(2);
001275 CREATE TABLE t1(a INT); INSERT INTO t1 VALUES(1);
001276 CREATE TABLE t2(b INT); INSERT INTO t2 VALUES(2);
001277 CREATE TABLE t3(c INT, d INT); INSERT INTO t3 VALUES(3,4);
001278 CREATE TABLE t4(e INT); INSERT INTO t4 VALUES(5);
001279 CREATE VIEW v5(x,y) AS SELECT c, d FROM t3 LEFT JOIN t4 ON false;
001280 }
001281 do_execsql_test join-30.2 {
001282 SELECT DISTINCT a, b
001283 FROM t1 RIGHT JOIN t2 ON a=b LEFT JOIN v5 ON false
001284 WHERE x <= y;
001285 } {}
001286 do_execsql_test join-30.3 {
001287 SELECT DISTINCT a, b
001288 FROM t0 JOIN t1 ON z=a RIGHT JOIN t2 ON a=b LEFT JOIN v5 ON false
001289 WHERE x <= y;
001290 } {}
001291
001292 finish_test