xref: /sqlite-3.40.0/test/join8.test (revision b88bf865)
1f7309bceSdrh# 2022-04-12
2f7309bceSdrh#
3f7309bceSdrh# The author disclaims copyright to this source code.  In place of
4f7309bceSdrh# a legal notice, here is a blessing:
5f7309bceSdrh#
6f7309bceSdrh#    May you do good and not evil.
7f7309bceSdrh#    May you find forgiveness for yourself and forgive others.
8f7309bceSdrh#    May you share freely, never taking more than you give.
9f7309bceSdrh#
10f7309bceSdrh#***********************************************************************
11f7309bceSdrh#
12f7309bceSdrh# This file implements tests for RIGHT and FULL OUTER JOINs.
13f7309bceSdrh
14f7309bceSdrhset testdir [file dirname $argv0]
15f7309bceSdrhsource $testdir/tester.tcl
16f7309bceSdrh
17abb4e759Sdrhifcapable !vtab {
18abb4e759Sdrh  finish_test
191c69bc91Sdrh  return
20abb4e759Sdrh}
21abb4e759Sdrh
22f7309bceSdrhdb null NULL
23825ecf9cSdrh# EVIDENCE-OF: R-33754-02880 you can say "LEFT RIGHT JOIN" which is the
24825ecf9cSdrh# same as "FULL JOIN".
25f7309bceSdrhdo_execsql_test join8-10 {
26f7309bceSdrh  CREATE TABLE t1(a,b,c);
27f7309bceSdrh  CREATE TABLE t2(x,y);
28f7309bceSdrh  CREATE INDEX t2x ON t2(x);
29f7309bceSdrh  SELECT avg(DISTINCT b) FROM (SELECT * FROM t2 LEFT RIGHT JOIN t1 ON c);
30f7309bceSdrh} {NULL}
31a51379adSdrh
32a1848a5dSdrh# Pending optimization opportunity:
33a51379adSdrh# Row-value initialization subroutines must be called from with the
34a51379adSdrh# RIGHT JOIN body subroutine before the first use of any register containing
35a51379adSdrh# the results of that subroutine.  This seems dodgy.  Test case:
36a51379adSdrh#
37a1848a5dSdrhreset_db
38a1848a5dSdrhdo_execsql_test join8-1000 {
39a1848a5dSdrh  CREATE TABLE t1(a INTEGER PRIMARY KEY AUTOINCREMENT,b,c,d,e,f,g,h,j,k,l,m,n,o,p,q,r,s);
40a1848a5dSdrh  CREATE INDEX t1x1 ON t1(g+h,j,k);
41a1848a5dSdrh  CREATE INDEX t1x2 ON t1(b);
42a1848a5dSdrh  INSERT INTO t1 DEFAULT VALUES;
43a1848a5dSdrh} {}
44a1848a5dSdrhdo_catchsql_test join8-1010 {
45a1848a5dSdrh  SELECT a
46a1848a5dSdrh    FROM (
47a1848a5dSdrh          SELECT a
48a1848a5dSdrh            FROM (
49a1848a5dSdrh                  SELECT a
50a1848a5dSdrh                    FROM (
51a1848a5dSdrh                          SELECT a FROM t1 NATURAL LEFT JOIN t1
52a1848a5dSdrh                           WHERE (b, 2 ) IS ( SELECT 2 IN(2,2),2)
53a1848a5dSdrh                         )
54a1848a5dSdrh                    NATURAL LEFT FULL JOIN t1
55a1848a5dSdrh                   WHERE ( rowid , 1 )<=(CASE 5 WHEN 619 THEN 841 ELSE 3374391096 END,0)
56a1848a5dSdrh                   ORDER BY a ASC
57a1848a5dSdrh                 )
58a1848a5dSdrh            NATURAL LEFT JOIN t1
59a1848a5dSdrh           WHERE (b, 2 ) IS ( SELECT 3 IN(3,3),3)
60a1848a5dSdrh         )
61a1848a5dSdrh    NATURAL LEFT FULL JOIN t1
62a1848a5dSdrh   WHERE ( rowid , 1 )<=(CASE 5 WHEN 619 THEN 841 ELSE 3374391096 END,0)
63a1848a5dSdrh   ORDER BY a ASC;
64a1848a5dSdrh} {0 1}
65a51379adSdrh
66d875c7eeSdrh# Pending issue #2: (now resolved)
67a51379adSdrh# Jump to addrHalt inside the RIGHT JOIN body subroutine bypasses the
68a51379adSdrh# OP_Return, resulting in a subroutine loop.  Test case:
69a51379adSdrh#
70d875c7eeSdrhreset_db
71d875c7eeSdrhdo_execsql_test join8-2000 {
72d875c7eeSdrh  CREATE TABLE t1(a int, b int, c int);
73d875c7eeSdrh  INSERT INTO t1 VALUES(1,2,3),(4,5,6);
74d875c7eeSdrh  CREATE TABLE t2(d int, e int);
75d875c7eeSdrh  INSERT INTO t2 VALUES(3,333),(4,444);
76d875c7eeSdrh  CREATE TABLE t3(f int, g int);
77d875c7eeSdrh  PRAGMA automatic_index=off;
78d875c7eeSdrh} {}
79d875c7eeSdrhdo_catchsql_test join8-2010 {
80d875c7eeSdrh  SELECT * FROM t1 RIGHT JOIN t2 ON c=d JOIN t3 ON f=e;
81d875c7eeSdrh} {0 {}}
82a51379adSdrh
836fda176bSdrh# Demonstrate that nested FULL JOINs and USING clauses work
84a51379adSdrh#
856fda176bSdrhreset_db
866fda176bSdrhload_static_extension db series
876fda176bSdrhdo_execsql_test join8-3000 {
886fda176bSdrh  CREATE TABLE t1(id INTEGER PRIMARY KEY, a INT);
896fda176bSdrh  CREATE TABLE t2(id INTEGER PRIMARY KEY, b INT);
906fda176bSdrh  CREATE TABLE t3(id INTEGER PRIMARY KEY, c INT);
916fda176bSdrh  CREATE TABLE t4(id INTEGER PRIMARY KEY, d INT);
926fda176bSdrh  CREATE TABLE t5(id INTEGER PRIMARY KEY, e INT);
936fda176bSdrh  CREATE TABLE t6(id INTEGER PRIMARY KEY, f INT);
946fda176bSdrh  CREATE TABLE t7(id INTEGER PRIMARY KEY, g INT);
956fda176bSdrh  CREATE TABLE t8(id INTEGER PRIMARY KEY, h INT);
966fda176bSdrh  INSERT INTO t1 SELECT value, 1 FROM generate_series(1,256) WHERE value & 1;
976fda176bSdrh  INSERT INTO t2 SELECT value, 1 FROM generate_series(1,256) WHERE value & 2;
986fda176bSdrh  INSERT INTO t3 SELECT value, 1 FROM generate_series(1,256) WHERE value & 4;
996fda176bSdrh  INSERT INTO t4 SELECT value, 1 FROM generate_series(1,256) WHERE value & 8;
1006fda176bSdrh  INSERT INTO t5 SELECT value, 1 FROM generate_series(1,256) WHERE value & 16;
1016fda176bSdrh  INSERT INTO t6 SELECT value, 1 FROM generate_series(1,256) WHERE value & 32;
1026fda176bSdrh  INSERT INTO t7 SELECT value, 1 FROM generate_series(1,256) WHERE value & 64;
1036fda176bSdrh  INSERT INTO t8 SELECT value, 1 FROM generate_series(1,256) WHERE value & 128;
1046fda176bSdrh  CREATE TABLE t9 AS
1056fda176bSdrh    SELECT id, h, g, f, e, d, c, b, a
1066fda176bSdrh      FROM t1
1076fda176bSdrh      NATURAL FULL JOIN t2
1086fda176bSdrh      NATURAL FULL JOIN t3
1096fda176bSdrh      NATURAL FULL JOIN t4
1106fda176bSdrh      NATURAL FULL JOIN t5
1116fda176bSdrh      NATURAL FULL JOIN t6
1126fda176bSdrh      NATURAL FULL JOIN t7
1136fda176bSdrh      NATURAL FULL JOIN t8;
1146fda176bSdrh} {}
1156fda176bSdrhdo_execsql_test join8-3010 {
1166fda176bSdrh  SELECT count(*) FROM t9;
1176fda176bSdrh} {255}
1186fda176bSdrhdo_execsql_test join8-3020 {
1196fda176bSdrh  SELECT id, count(*) FROM t9 GROUP BY id HAVING count(*)!=1;
1206fda176bSdrh} {}
1216fda176bSdrhdo_execsql_test join8-3030 {
1226fda176bSdrh  UPDATE t9 SET a=0 WHERE a IS NULL;
1236fda176bSdrh  UPDATE t9 SET b=0 WHERE b IS NULL;
1246fda176bSdrh  UPDATE t9 SET c=0 WHERE c IS NULL;
1256fda176bSdrh  UPDATE t9 SET d=0 WHERE d IS NULL;
1266fda176bSdrh  UPDATE t9 SET e=0 WHERE e IS NULL;
1276fda176bSdrh  UPDATE t9 SET f=0 WHERE f IS NULL;
1286fda176bSdrh  UPDATE t9 SET g=0 WHERE g IS NULL;
1296fda176bSdrh  UPDATE t9 SET h=0 WHERE h IS NULL;
1306fda176bSdrh  SELECT count(*) FROM t9 WHERE id=128*h+64*g+32*f+16*e+8*d+4*c+2*b+a;
1316fda176bSdrh} {255}
1326fda176bSdrhdo_execsql_test join8-3040 {
1336fda176bSdrh  SELECT * FROM t9 WHERE id<>128*h+64*g+32*f+16*e+8*d+4*c+2*b+a;
1346fda176bSdrh} {}
1356fda176bSdrh
136503ad9c7Sdrh# 2022-04-21 dbsqlfuzz find
137503ad9c7Sdrh#
138503ad9c7Sdrhreset_db
139503ad9c7Sdrhdo_execsql_test join8-4000 {
140503ad9c7Sdrh  CREATE TABLE t1(x INTEGER PRIMARY KEY, a, b);
141503ad9c7Sdrh  INSERT INTO t1 VALUES(1,5555,4);
142503ad9c7Sdrh  CREATE INDEX i1a ON t1(a);
143503ad9c7Sdrh  CREATE INDEX i1b ON t1(b);
144503ad9c7Sdrh  SELECT a FROM t1 NATURAL RIGHT JOIN t1 WHERE a=5555 OR (1,b)==(SELECT 2 IN (2,2),4);
145503ad9c7Sdrh} {5555}
146a51379adSdrh
147ecb386b7Sdrh# 2022-04-23 dbsqlfuzz c7ee5500e3abddec3557016de777713b80c790d3
148ecb386b7Sdrh# Escape from the right-join body subroutine via the ORDER BY LIMIT optimization.
149ecb386b7Sdrh#
150ecb386b7Sdrhreset_db
151ecb386b7Sdrhdb null -
152ecb386b7Sdrhdo_catchsql_test join8-5000 {
153ecb386b7Sdrh  CREATE TABLE t1(x);
154ecb386b7Sdrh  INSERT INTO t1(x) VALUES(NULL),(NULL);
155ecb386b7Sdrh  CREATE TABLE t2(c, d);
156ecb386b7Sdrh  INSERT INTO t2(c,d) SELECT x, x FROM t1;
157ecb386b7Sdrh  CREATE INDEX t2dc ON t2(d, c);
158ecb386b7Sdrh  SELECT (SELECT c FROM sqlite_temp_schema FULL JOIN t2 ON d IN (1,2,3) ORDER BY d) AS x FROM t1;
159ecb386b7Sdrh} {0 {- -}}
160ecb386b7Sdrh
1613d566536Sdrh# 2022-04-29 dbsqlfuzz 19f1102a70cf966ab249de56d944fc20dbebcfcf
1623d566536Sdrh#
1633d566536Sdrhreset_db
1643d566536Sdrhdo_execsql_test join8-6000 {
1653d566536Sdrh  CREATE TABLE t1(a INTEGER PRIMARY KEY, b TEXT, c TEXT, d REAL);
1663d566536Sdrh  INSERT INTO t1 VALUES(1,'A','aa',2.5);
1673d566536Sdrh  SELECT * FROM t1 AS t2 NATURAL RIGHT JOIN t1 AS t3
1683d566536Sdrh   WHERE (a,b) IN (SELECT rowid, b FROM t1);
1693d566536Sdrh} {1 A aa 2.5}
170a25bbaf7Sdrhdo_execsql_test join8-6010 {
171a25bbaf7Sdrh  DROP TABLE IF EXISTS t1;
172a25bbaf7Sdrh  CREATE TABLE t1(a INT PRIMARY KEY, b TEXT, c TEXT, d INT) WITHOUT ROWID;
173a25bbaf7Sdrh  INSERT INTO t1 VALUES(15,'xray','baker',42);
174a25bbaf7Sdrh  SELECT value, t1.* FROM json_each('7') NATURAL RIGHT JOIN t1
175a25bbaf7Sdrh   WHERE (a,b) IN (SELECT a, b FROM t1);
176a25bbaf7Sdrh} {7 15 xray baker 42}
17774973647Sdrhdo_execsql_test join8-6020 {
17874973647Sdrh  DROP TABLE IF EXISTS t1;
17974973647Sdrh  CREATE TABLE t1(a INTEGER PRIMARY KEY,b);
18074973647Sdrh  INSERT INTO t1 VALUES(0,NULL),(1,2);
18174973647Sdrh  SELECT value, t1.* FROM json_each('17') NATURAL RIGHT JOIN t1
18274973647Sdrh   WHERE (a,b) IN (SELECT rowid, b FROM t1);
18374973647Sdrh} {17 1 2}
1843d566536Sdrh
18511d63ebfSdrh# Bloom filter usage by RIGHT and FULL JOIN
18611d63ebfSdrh#
18711d63ebfSdrhreset_db
18811d63ebfSdrhdo_execsql_test join8-7000 {
18911d63ebfSdrhCREATE TABLE t1(a INT, b INT, c INT, d INT);
19011d63ebfSdrh  WITH RECURSIVE c(x) AS (VALUES(0) UNION ALL SELECT x+1 FROM c WHERE x<10)
19111d63ebfSdrh    INSERT INTO t1(a,b,c,d) SELECT x, x+100, x+200, x+300 FROM c;
19211d63ebfSdrh  CREATE TABLE t2(b INT, x INT);
19311d63ebfSdrh  INSERT INTO t2(b,x) SELECT b, a FROM t1 WHERE a%2=0;
19411d63ebfSdrh  CREATE INDEX t2b ON t2(b);
19511d63ebfSdrh  CREATE TABLE t3(c INT, y INT);
19611d63ebfSdrh  INSERT INTO t3(c,y) SELECT c, a FROM t1 WHERE a%3=0;
19711d63ebfSdrh  CREATE INDEX t3c ON t3(c);
19811d63ebfSdrh  CREATE TABLE t4(d INT, z INT);
19911d63ebfSdrh  INSERT INTO t4(d,z) SELECT d, a FROM t1 WHERE a%5=0;
20011d63ebfSdrh  CREATE INDEX t4d ON t4(d);
20111d63ebfSdrh  INSERT INTO t1(a,b,c,d) VALUES
20211d63ebfSdrh    (96,NULL,296,396),
20311d63ebfSdrh    (97,197,NULL,397),
20411d63ebfSdrh    (98,198,298,NULL),
20511d63ebfSdrh    (99,NULL,NULL,NULL);
20611d63ebfSdrh  ANALYZE sqlite_schema;
20711d63ebfSdrh  INSERT INTO sqlite_stat1 VALUES('t4','t4d','20 1');
20811d63ebfSdrh  INSERT INTO sqlite_stat1 VALUES('t3','t3c','32 1');
20911d63ebfSdrh  INSERT INTO sqlite_stat1 VALUES('t2','t2b','48 1');
21011d63ebfSdrh  INSERT INTO sqlite_stat1 VALUES('t1',NULL,'100');
21111d63ebfSdrh  ANALYZE sqlite_schema;
21211d63ebfSdrh} {}
21311d63ebfSdrhdb null -
21411d63ebfSdrhdo_execsql_test join8-7010 {
21511d63ebfSdrh  WITH t0 AS MATERIALIZED (
21611d63ebfSdrh    SELECT t1.*, t2.*, t3.*
21711d63ebfSdrh      FROM t1 INNER JOIN t2 ON t1.b=t2.b AND t2.x>0
21811d63ebfSdrh        RIGHT JOIN t3 ON t1.c=t3.c AND t3.y>0
21911d63ebfSdrh  )
22011d63ebfSdrh  SELECT * FROM t0 FULL JOIN t4 ON t0.a=t4.d AND t4.z>0
22111d63ebfSdrh   ORDER BY coalesce(t0.a, t0.y+200, t4.d);
22211d63ebfSdrh} {
22311d63ebfSdrh  6  106  206  306  106  6  206  6    -   -
22411d63ebfSdrh  -    -    -    -    -  -  200  0    -   -
22511d63ebfSdrh  -    -    -    -    -  -  203  3    -   -
22611d63ebfSdrh  -    -    -    -    -  -  209  9    -   -
22711d63ebfSdrh  -    -    -    -    -  -    -  -  300   0
22811d63ebfSdrh  -    -    -    -    -  -    -  -  305   5
22911d63ebfSdrh  -    -    -    -    -  -    -  -  310  10
23011d63ebfSdrh}
231825ecf9cSdrh
232825ecf9cSdrh# EVIDENCE-OF: R-33754-02880 you can say "LEFT RIGHT JOIN" which is the
233825ecf9cSdrh# same as "FULL JOIN".
234825ecf9cSdrhdo_execsql_test join8-7011 {
235825ecf9cSdrh  WITH t0 AS MATERIALIZED (
236825ecf9cSdrh    SELECT t1.*, t2.*, t3.*
237825ecf9cSdrh      FROM t1 INNER JOIN t2 ON t1.b=t2.b AND t2.x>0
238825ecf9cSdrh        RIGHT JOIN t3 ON t1.c=t3.c AND t3.y>0
239825ecf9cSdrh  )
240825ecf9cSdrh  SELECT * FROM t0 LEFT RIGHT JOIN t4 ON t0.a=t4.d AND t4.z>0
241825ecf9cSdrh   ORDER BY coalesce(t0.a, t0.y+200, t4.d);
242825ecf9cSdrh} {
243825ecf9cSdrh  6  106  206  306  106  6  206  6    -   -
244825ecf9cSdrh  -    -    -    -    -  -  200  0    -   -
245825ecf9cSdrh  -    -    -    -    -  -  203  3    -   -
246825ecf9cSdrh  -    -    -    -    -  -  209  9    -   -
247825ecf9cSdrh  -    -    -    -    -  -    -  -  300   0
248825ecf9cSdrh  -    -    -    -    -  -    -  -  305   5
249825ecf9cSdrh  -    -    -    -    -  -    -  -  310  10
250825ecf9cSdrh}
251825ecf9cSdrh
25211d63ebfSdrhdo_execsql_test join8-7020 {
25311d63ebfSdrh  EXPLAIN QUERY PLAN
25411d63ebfSdrh  WITH t0 AS MATERIALIZED (
25511d63ebfSdrh    SELECT t1.*, t2.*, t3.*
25611d63ebfSdrh      FROM t1 INNER JOIN t2 ON t1.b=t2.b AND t2.x>0
25711d63ebfSdrh        RIGHT JOIN t3 ON t1.c=t3.c AND t3.y>0
25811d63ebfSdrh  )
25911d63ebfSdrh  SELECT * FROM t0 FULL JOIN t4 ON t0.a=t4.d AND t4.z>0
26011d63ebfSdrh   ORDER BY coalesce(t0.a, t0.y+200, t4.d);
26111d63ebfSdrh} {/.*BLOOM FILTER ON t2.*BLOOM FILTER ON t3.*BLOOM FILTER ON t4.*/}
26211d63ebfSdrh
263d631c6afSdrh# 2022-05-12 Difference with PG found (by Dan) while exploring
264d631c6afSdrh# https://sqlite.org/forum/forumpost/677a0ab93fcd9ccd
265d631c6afSdrh#
266d631c6afSdrhreset_db
267d631c6afSdrhdo_execsql_test join8-8000 {
268d631c6afSdrh  CREATE TABLE t1(a INT, b INT);
269d631c6afSdrh  CREATE TABLE t2(c INT, d INT);
270d631c6afSdrh  CREATE TABLE t3(e INT, f INT);
271d631c6afSdrh  INSERT INTO t1 VALUES(1, 2);
272d631c6afSdrh  INSERT INTO t2 VALUES(3, 4);
273d631c6afSdrh  INSERT INTO t3 VALUES(5, 6);
274d631c6afSdrh} {}
275d631c6afSdrhdo_execsql_test join8-8010 {
276d631c6afSdrh  SELECT *
277d631c6afSdrh    FROM t3 LEFT JOIN t2 ON true
278d631c6afSdrh            JOIN t1 ON (t3.e IS t2.c);
279d631c6afSdrh} {}
280d631c6afSdrhdo_execsql_test join8-8020 {
281d631c6afSdrh  SELECT *
282d631c6afSdrh    FROM t3 LEFT JOIN t2 ON true
283d631c6afSdrh            JOIN t1 ON (t3.e IS NOT DISTINCT FROM t2.c);
284d631c6afSdrh} {}
285d631c6afSdrh
286f69dad8cSdrh# 2022-05-13 The idea of reusing subquery cursors does not
287f69dad8cSdrh# work, if the cursors are used both for scanning and lookups.
288f69dad8cSdrh#
289f69dad8cSdrhreset_db
290f69dad8cSdrhdb null -
291f69dad8cSdrhdo_execsql_test join8-9000 {
292f69dad8cSdrh  CREATE TABLE t1(a INTEGER PRIMARY KEY, b TEXT, c TEXT, d REAL);
293f69dad8cSdrh  INSERT INTO t1 VALUES(1,'E','bb',NULL),(2,NULL,NULL,NULL);
294f69dad8cSdrh  SELECT * FROM t1 NATURAL RIGHT JOIN t1 AS t2 WHERE (a,b) IN (SELECT a+0, b FROM t1);
295f69dad8cSdrh} {1 E bb -}
296f69dad8cSdrh
297c93bf1d4Sdrh# 2022-05-14 https://sqlite.org/forum/forumpost/c06b10ad7e
298c93bf1d4Sdrh#
299c93bf1d4Sdrhreset_db
300c93bf1d4Sdrhdb null -
301c93bf1d4Sdrhdo_execsql_test join8-10000 {
302c93bf1d4Sdrh  CREATE TABLE t1(c0 INT UNIQUE);
303c93bf1d4Sdrh  CREATE TABLE t2(c0);
304c93bf1d4Sdrh  CREATE TABLE t2i(c0 INT);
305c93bf1d4Sdrh  CREATE TABLE t3(c0 INT);
306c93bf1d4Sdrh  INSERT INTO t1 VALUES(1);
307c93bf1d4Sdrh  INSERT INTO t2 VALUES(2);
308c93bf1d4Sdrh  INSERT INTO t2i VALUES(2);
309c93bf1d4Sdrh  INSERT INTO t3 VALUES(3);
310c93bf1d4Sdrh} {}
311c93bf1d4Sdrhdo_execsql_test join8-10010 {
312c93bf1d4Sdrh  SELECT DISTINCT t1.c0, t3.c0
313c93bf1d4Sdrh    FROM t2 NATURAL JOIN t1 RIGHT JOIN t3 ON t1.c0;
314c93bf1d4Sdrh} {- 3}
315c93bf1d4Sdrhdo_execsql_test join8-10020 {
316c93bf1d4Sdrh  SELECT t1.c0, t3.c0
317c93bf1d4Sdrh    FROM t2 NATURAL JOIN t1 RIGHT JOIN t3 ON t1.c0;
318c93bf1d4Sdrh} {- 3}
319c93bf1d4Sdrhdo_execsql_test join8-10030 {
320c93bf1d4Sdrh  SELECT DISTINCT t1.c0, t3.c0
321c93bf1d4Sdrh    FROM t2 NATURAL CROSS JOIN t1 RIGHT JOIN t3 ON t1.c0;
322c93bf1d4Sdrh} {- 3}
323c93bf1d4Sdrhdo_execsql_test join8-10040 {
324c93bf1d4Sdrh  SELECT t1.c0, t3.c0
325c93bf1d4Sdrh    FROM t1 NATURAL CROSS JOIN t2 RIGHT JOIN t3 ON t1.c0;
326c93bf1d4Sdrh} {- 3}
327c93bf1d4Sdrhdo_execsql_test join8-10050 {
328c93bf1d4Sdrh  SELECT DISTINCT t1.c0, t3.c0
329c93bf1d4Sdrh    FROM t2i NATURAL JOIN t1 RIGHT JOIN t3 ON t1.c0;
330c93bf1d4Sdrh} {- 3}
331c93bf1d4Sdrhdo_execsql_test join8-10060 {
332c93bf1d4Sdrh  SELECT DISTINCT +t1.c0, t3.c0
333c93bf1d4Sdrh    FROM t2 NATURAL JOIN t1 RIGHT JOIN t3 ON t1.c0;
334c93bf1d4Sdrh} {- 3}
335c93bf1d4Sdrhdo_execsql_test join8-10070 {
336c93bf1d4Sdrh  SELECT DISTINCT +t1.c0, t3.c0
337c93bf1d4Sdrh    FROM t1 NATURAL CROSS JOIN t2 RIGHT JOIN t3 ON t1.c0;
338c93bf1d4Sdrh} {- 3}
339c93bf1d4Sdrhdo_execsql_test join8-10080 {
340c93bf1d4Sdrh  SELECT DISTINCT t1.c0, t3.c0
341c93bf1d4Sdrh    FROM t2 NATURAL JOIN t1 RIGHT JOIN t3 ON t1.c0<>0;
342c93bf1d4Sdrh} {- 3}
343c93bf1d4Sdrh
34496d55497Sdrh# 2022-05-14
34596d55497Sdrh# index-on-expr scan on a RIGHT JOIN
34696d55497Sdrh# dbsqlfuzz 39ee60004ff027a9e2846cf76e02cd5ac0953739
34796d55497Sdrh#
34896d55497Sdrhreset_db
34996d55497Sdrhdb null -
35096d55497Sdrhdo_execsql_test join8-11000 {
35196d55497Sdrh  CREATE TABLE t1(a);
35296d55497Sdrh  CREATE TABLE t2(b);
35396d55497Sdrh  INSERT INTO t2 VALUES(0),(1),(2);
35496d55497Sdrh  SELECT * FROM t1 RIGHT JOIN t2 ON (a=b) WHERE 99+(b+1)!=99;
35596d55497Sdrh} {- 0 - 1 - 2}
35696d55497Sdrhdo_execsql_test join8-11010 {
35796d55497Sdrh  CREATE INDEX t2b ON t2(b+1) WHERE b IS NOT NULL;
35896d55497Sdrh  SELECT * FROM t1 RIGHT JOIN t2 ON (a=b) WHERE 99+(b+1)!=99;
35996d55497Sdrh} {- 0 - 1 - 2}
36096d55497Sdrhdo_execsql_test join8-11020 {
36196d55497Sdrh  DROP TABLE t1;
36296d55497Sdrh  DROP TABLE t2;
36396d55497Sdrh  CREATE TABLE t1(a);
36496d55497Sdrh  CREATE TABLE t2(b, c, d);
36596d55497Sdrh  INSERT INTO t2 VALUES(1, 3, 'not-4');
36696d55497Sdrh  SELECT b, d FROM t1 RIGHT JOIN t2 WHERE (b+0)=1 AND d!=4;
36796d55497Sdrh} {1 not-4}
36896d55497Sdrhdo_execsql_test join8-11030 {
36996d55497Sdrh  CREATE INDEX i2 ON t2((b+0), d);
37096d55497Sdrh  SELECT b, d FROM t1 RIGHT JOIN t2 WHERE (b+0)=1 AND d!=4;
37196d55497Sdrh} {1 not-4}
37296d55497Sdrhdo_execsql_test join8-11040 {
37396d55497Sdrh  DROP INDEX i2;
37496d55497Sdrh  CREATE INDEX i2 ON t2((b+0), d) WHERE d IS NOT NULL;
37596d55497Sdrh  SELECT b, d FROM t1 RIGHT JOIN t2 WHERE (b+0)=1 AND d!=4;
37696d55497Sdrh} {1 not-4}
37796d55497Sdrh
378ea488b12Sdrh# 2022-05-23
379ea488b12Sdrh# NATURAL JOIN name resolution is more forgiving with LEFT JOIN
380ea488b12Sdrh# https://sqlite.org/forum/forumpost/e90a8e6e6f
381ea488b12Sdrh#
382ea488b12Sdrhreset_db
383ea488b12Sdrhdb null -
384ea488b12Sdrhdo_execsql_test join8-12000 {
385ea488b12Sdrh  CREATE TABLE t1(a INT);  INSERT INTO t1 VALUES(0),(1);
386ea488b12Sdrh  CREATE TABLE t2(a INT);  INSERT INTO t2 VALUES(0),(2);
387ea488b12Sdrh  CREATE TABLE t3(a INT);  INSERT INTO t3 VALUES(0),(3);
388ea488b12Sdrh} {}
389ea488b12Sdrhdo_catchsql_test join8-12010 {
390ea488b12Sdrh  SELECT * FROM t1 RIGHT JOIN t2 ON t2.a<>0 NATURAL RIGHT JOIN t3;
391ea488b12Sdrh} {1 {ambiguous reference to a in USING()}}
392ea488b12Sdrhdo_catchsql_test join8-12020 {
393ea488b12Sdrh  SELECT * FROM t1 RIGHT JOIN t2 ON t2.a<>0 NATURAL LEFT JOIN t3;
394ea488b12Sdrh} {1 {ambiguous reference to a in USING()}}
395ea488b12Sdrhdo_catchsql_test join8-12030 {
396ea488b12Sdrh  SELECT * FROM t1 LEFT JOIN t2 ON t2.a<>0 NATURAL RIGHT JOIN t3;
397ea488b12Sdrh} {1 {ambiguous reference to a in USING()}}
398ea488b12Sdrh
399ea488b12Sdrh# The following query should probably also return the same error as the
400ea488b12Sdrh# previous three cases.  However, historical versions of SQLite have always
401ea488b12Sdrh# let it pass.  We will not "fix" this, since to do so might break legacy
402ea488b12Sdrh# applications.
403ea488b12Sdrh#
404ea488b12Sdrhdo_catchsql_test join8-12040 {
405ea488b12Sdrh  SELECT * FROM t1 LEFT JOIN t2 ON t2.a<>0 NATURAL LEFT JOIN t3;
406ea488b12Sdrh} {0 {0 2 1 2}}
407ea488b12Sdrh
4086af03b46Sdrh# 2022-05-24
4096af03b46Sdrh# https://sqlite.org/forum/forumpost/687b0bf563a1d4f1
4106af03b46Sdrh#
4116af03b46Sdrhreset_db
4126af03b46Sdrhdo_execsql_test join8-13000 {
4136af03b46Sdrh  CREATE TABLE t0(t TEXT, u TEXT);  INSERT INTO t0 VALUES('t', 'u');
4146af03b46Sdrh  CREATE TABLE t1(v TEXT, w TEXT);  INSERT INTO t1 VALUES('v', 'w');
4156af03b46Sdrh  CREATE TABLE t2(x TEXT, y TEXT);  INSERT INTO t2 VALUES('x', 'y');
4166af03b46Sdrh  SELECT * FROM t0 JOIN t1 ON (t2.x NOTNULL) LEFT JOIN t2 ON false;
4176af03b46Sdrh  SELECT * FROM t0 JOIN t1 ON (t2.x NOTNULL) LEFT JOIN t2 ON false
4186af03b46Sdrh   WHERE t2.y ISNULL;
4196af03b46Sdrh} {}
420ea488b12Sdrh
4217bfbd250Sdrh# 2022-05-25
4227bfbd250Sdrh# https://sqlite.org/forum/forumpost/5cfe08eed6
4237bfbd250Sdrh#
4247bfbd250Sdrhreset_db
4257bfbd250Sdrhdo_execsql_test join8-14000 {
4267bfbd250Sdrh  CREATE TABLE t0(a TEXT, b TEXT, c TEXT);
4277bfbd250Sdrh  CREATE TABLE t1(a TEXT);
4287bfbd250Sdrh  INSERT INTO t1 VALUES('1');
4297bfbd250Sdrh  CREATE VIEW v0 AS SELECT 'xyz' AS d;
4307bfbd250Sdrh  SELECT * FROM v0 RIGHT JOIN t1 ON t1.a<>'' INNER JOIN t0 ON t0.c<>'';
4317bfbd250Sdrh  SELECT * FROM v0 RIGHT JOIN t1 ON t1.a<>'' INNER JOIN t0 ON t0.c<>'' WHERE b ISNULL;
4327bfbd250Sdrh} {}
4337bfbd250Sdrhdo_execsql_test join8-14010 {
4347bfbd250Sdrh  CREATE TABLE y0(a INT);
4357bfbd250Sdrh  CREATE TABLE y1(b INT); INSERT INTO y1 VALUES(1), (2);
4367bfbd250Sdrh  CREATE TABLE y2(c INT); INSERT INTO y2 VALUES(3), (4);
4377bfbd250Sdrh} {}
4387bfbd250Sdrhdb null -
4397bfbd250Sdrhdo_execsql_test join8-14020 {
4407bfbd250Sdrh  SELECT * FROM y0 RIGHT JOIN y1 ON true INNER JOIN y2 ON true WHERE y2.c!=99 AND y2.c!=98;
4417bfbd250Sdrh} {
4427bfbd250Sdrh  - 1 3
4437bfbd250Sdrh  - 1 4
4447bfbd250Sdrh  - 2 3
4457bfbd250Sdrh  - 2 4
4467bfbd250Sdrh}
4477bfbd250Sdrh
448404bf6baSdrh# 2022-05-30
449404bf6baSdrh# https://sqlite.org/forum/forumpost/3902c7b833
450404bf6baSdrh#
451404bf6baSdrhreset_db
452404bf6baSdrhdo_execsql_test join8-15000 {
453404bf6baSdrh  CREATE TABLE t1(x INT);
454404bf6baSdrh  CREATE TABLE t2(y INT);
455404bf6baSdrh  CREATE TABLE t3(z INT);
456404bf6baSdrh  INSERT INTO t1 VALUES(10);
457404bf6baSdrh  INSERT INTO t3 VALUES(20),(30);
458404bf6baSdrh}
459404bf6baSdrhdo_execsql_test join8-15010 {
460404bf6baSdrh  SELECT * FROM t1 LEFT JOIN t2 ON true JOIN t3 ON t2.y IS NOT NULL;
461404bf6baSdrh} {}
462404bf6baSdrhdo_execsql_test join8-15020 {
463404bf6baSdrh  SELECT * FROM t1 LEFT JOIN t2 ON true JOIN t3 ON t2.y IS NOT NULL
464404bf6baSdrh   WHERE (t3.z!=400 AND t3.z!=500 AND t3.z!=600);
465404bf6baSdrh} {}
466404bf6baSdrhdo_execsql_test join8-15100 {
467404bf6baSdrh  PRAGMA automatic_index = 0;
468404bf6baSdrh  CREATE TABLE t4(x TEXT);
469404bf6baSdrh  CREATE TABLE t5(y TEXT);
470404bf6baSdrh  CREATE TABLE t6(z TEXT);
471404bf6baSdrh  INSERT INTO t4 VALUES('a'), ('b');
472404bf6baSdrh  INSERT INTO t5 VALUES('b'), ('c');
473404bf6baSdrh  INSERT INTO t6 VALUES('a'), ('d');
474404bf6baSdrh} {}
475404bf6baSdrhdb null -
476404bf6baSdrhdo_execsql_test join8-15110 {
477404bf6baSdrh  SELECT * FROM t4 LEFT JOIN t5 ON x=y LEFT JOIN t6 ON (x=z) ORDER BY +x;
478404bf6baSdrh} {a - a b b -}
479404bf6baSdrhdo_execsql_test join8-15120 {
480404bf6baSdrh  SELECT * FROM t4 LEFT JOIN t5 ON x=y LEFT JOIN t6 ON (x=z)
481404bf6baSdrh   WHERE t5.y!='x' AND t4.x!='x';
482404bf6baSdrh} {b b -}
483404bf6baSdrh
484b1f08bc6Sdrh# 2022-05-31
485b1f08bc6Sdrh# https://sqlite.org/forum/forumpost/c2554d560b
486b1f08bc6Sdrhreset_db
487b1f08bc6Sdrhdo_execsql_test join8-16000 {
488b1f08bc6Sdrh  CREATE TABLE t1(a TEXT);
489b1f08bc6Sdrh  CREATE TABLE t2(b TEXT);
490b1f08bc6Sdrh  CREATE TABLE t3(c TEXT);
491b1f08bc6Sdrh  INSERT INTO t2(b) VALUES ('x');
492b1f08bc6Sdrh  INSERT INTO t3(c) VALUES ('y'), ('z');
493b1f08bc6Sdrh} {}
494b1f08bc6Sdrhdb null -
495b1f08bc6Sdrhdo_execsql_test join8-16010 {
496b1f08bc6Sdrh  SELECT * FROM t1 RIGHT JOIN t2 ON true LEFT JOIN t3 ON a<>'';
497b1f08bc6Sdrh} {- x -}
498b1f08bc6Sdrhdo_execsql_test join8-16020 {
499b1f08bc6Sdrh  SELECT * FROM t1 RIGHT JOIN t2 ON true LEFT JOIN t3 ON a<>'' WHERE c IS NULL;
500b1f08bc6Sdrh} {- x -}
501b1f08bc6Sdrhdo_execsql_test join8-16020 {
502b1f08bc6Sdrh  SELECT * FROM t1 RIGHT JOIN t2 ON true JOIN t3 ON a<>'' WHERE c IS NULL;
503b1f08bc6Sdrh} {}
504b1f08bc6Sdrhdo_execsql_test join8-16030 {
505b1f08bc6Sdrh  SELECT * FROM t1 RIGHT JOIN t2 ON true JOIN t3 ON a<>'';
506b1f08bc6Sdrh} {}
507b1f08bc6Sdrhdo_execsql_test join8-16040 {
508b1f08bc6Sdrh  SELECT * FROM t1 RIGHT JOIN t2 ON true LEFT JOIN t3 ON a<>'' WHERE c<>'';
509b1f08bc6Sdrh} {}
510b1f08bc6Sdrhdo_execsql_test join8-16050 {
511b1f08bc6Sdrh  SELECT * FROM t1 RIGHT JOIN t2 ON true LEFT JOIN t3 ON a<>'' WHERE c IS NOT NULL;
512b1f08bc6Sdrh} {}
513b1f08bc6Sdrhdo_execsql_test join8-16060 {
514b1f08bc6Sdrh  SELECT * FROM t1 RIGHT JOIN t2 ON true JOIN t3 ON a<>'' WHERE c<>'';
515b1f08bc6Sdrh} {}
516b1f08bc6Sdrhdo_execsql_test join8-16070 {
517b1f08bc6Sdrh  SELECT * FROM t1 RIGHT JOIN t2 ON true JOIN t3 ON a<>'' WHERE c IS NOT NULL;
518b1f08bc6Sdrh} {}
519404bf6baSdrh
52036c19f77Sdrh# 2022-06-01
52136c19f77Sdrh# https://sqlite.org/forum/forumpost/087de2d9ec
52236c19f77Sdrh#
52336c19f77Sdrhreset_db
52436c19f77Sdrhdo_execsql_test join8-17000 {
52536c19f77Sdrh  CREATE TABLE t1(id INTEGER PRIMARY KEY, x INT, y INT);
52636c19f77Sdrh  CREATE TABLE t2(z INT);
5270286cdbcSdrh  INSERT INTO t1(id,x,y) VALUES(1, 0, 0);
52836c19f77Sdrh} {}
52936c19f77Sdrhdb null NULL
53036c19f77Sdrhdo_execsql_test join8-17010 {
53136c19f77Sdrh  SELECT * FROM t2 RIGHT JOIN t1 ON true;
53236c19f77Sdrh} {NULL 1 0 0}
53336c19f77Sdrhdo_execsql_test join8-17020 {
5340286cdbcSdrh  SELECT 99=id AND 0=y AS "truth" FROM t2 RIGHT JOIN t1 ON true;
5350286cdbcSdrh} {0}
53636c19f77Sdrhdo_execsql_test join8-17030 {
5370286cdbcSdrh  SELECT (99, 0)==(id, y) AS "truth" FROM t2 RIGHT JOIN t1;
5380286cdbcSdrh} {0}
53936c19f77Sdrhdo_execsql_test join8-17040 {
5400286cdbcSdrh  SELECT * FROM t2 RIGHT JOIN t1 WHERE 99=id AND 0=y;
5410286cdbcSdrh} {}
5420286cdbcSdrhdo_execsql_test join8-17041 {
5430286cdbcSdrh  SELECT * FROM t2 RIGHT JOIN t1 WHERE 99=+id AND 0=y;
54436c19f77Sdrh} {}
54536c19f77Sdrhdo_execsql_test join8-17050 {
5460286cdbcSdrh  SELECT * FROM t2 RIGHT JOIN t1 WHERE (99, 0)==(id,y);
54736c19f77Sdrh} {}
5480286cdbcSdrhdo_execsql_test join8-17051 {
5490286cdbcSdrh  SELECT * FROM t2 RIGHT JOIN t1 WHERE (99, 0)==(+id,y);
5500286cdbcSdrh} {}
5510286cdbcSdrhdo_execsql_test join8-17060 {
5520286cdbcSdrh  SELECT * FROM t2 RIGHT JOIN t1 WHERE 1=id AND 0=y;
5530286cdbcSdrh} {NULL 1 0 0}
5540286cdbcSdrhdo_execsql_test join8-17061 {
5550286cdbcSdrh  SELECT * FROM t2 RIGHT JOIN t1 WHERE 1=+id AND 0=y;
5560286cdbcSdrh} {NULL 1 0 0}
5570286cdbcSdrhdo_execsql_test join8-17070 {
5580286cdbcSdrh  SELECT * FROM t2 RIGHT JOIN t1 WHERE (1, 0)==(id,y);
5590286cdbcSdrh} {NULL 1 0 0}
5600286cdbcSdrhdo_execsql_test join8-17071 {
5610286cdbcSdrh  SELECT * FROM t2 RIGHT JOIN t1 WHERE (1, 0)==(+id,y);
5620286cdbcSdrh} {NULL 1 0 0}
563a5d06a3dSdrhdo_execsql_test join8-17080 {
564a5d06a3dSdrh  CREATE TABLE t3(a INTEGER PRIMARY KEY, b INT);
565a5d06a3dSdrh  CREATE TABLE t4(x INT, y INT);
566a5d06a3dSdrh  INSERT INTO t3(a,b) VALUES(1, 3);
567a5d06a3dSdrh} {}
568a5d06a3dSdrhdo_execsql_test join8-17090 {
569a5d06a3dSdrh  SELECT t3.a FROM t4 RIGHT JOIN t3 ON (x=a) WHERE (b, 4)=(SELECT 3, 4);
570a5d06a3dSdrh} {1}
571a5d06a3dSdrhdo_execsql_test join8-17091 {
572a5d06a3dSdrh  SELECT t3.a FROM t4 RIGHT JOIN t3 ON (x=a) WHERE (b, 4) IS (SELECT 3, 4);
573a5d06a3dSdrh} {1}
57436c19f77Sdrh
575c18fc613Sdrh# 2022-06-06
576c18fc613Sdrh# https://sqlite.org/forum/forumpost/206d99a16dd9212f
577c18fc613Sdrh# tag-20191211-001
578c18fc613Sdrh#
579c18fc613Sdrhreset_db
580c18fc613Sdrhdo_execsql_test join8-18000 {
581c18fc613Sdrh  CREATE TABLE t1(a BOOLEAN); INSERT INTO t1 VALUES (false);
582c18fc613Sdrh  CREATE TABLE t2(x INT);     INSERT INTO t2 VALUES (0);
583c18fc613Sdrh  SELECT *, x NOTNULL, (x NOTNULL)=a FROM t2 RIGHT JOIN t1 ON true WHERE (x NOTNULL)=a;
584c18fc613Sdrh} {}
585c18fc613Sdrhdo_execsql_test join8-18010 {
586c18fc613Sdrh  CREATE INDEX t1a ON t1(a);
587c18fc613Sdrh  SELECT *, x NOTNULL, (x NOTNULL)=a FROM t2 RIGHT JOIN t1 ON true WHERE (x NOTNULL)=a;
588c18fc613Sdrh} {}
589c18fc613Sdrh
59093c4087fSdando_execsql_test join8-18020 {
59193c4087fSdan  CREATE TABLE t3(z);
59293c4087fSdan  INSERT INTO t3 VALUES('t3value');
59393c4087fSdan  SELECT *, x NOTNULL, (x NOTNULL)=a FROM t2 RIGHT JOIN t1 ON true INNER JOIN t3 ON (x NOTNULL)=a;
59493c4087fSdan} {}
59593c4087fSdan
59693c4087fSdanifcapable rtree {
59793c4087fSdan  do_execsql_test join8-18030 {
59893c4087fSdan    CREATE VIRTUAL TABLE rtree1 USING rtree(a, x1, x2);
59993c4087fSdan    INSERT INTO rtree1 VALUES(0, 0, 0);
60093c4087fSdan  }
60193c4087fSdan  do_execsql_test join8-18040 {
60293c4087fSdan    SELECT *, x NOTNULL, (x NOTNULL)=a FROM t2
60393c4087fSdan      RIGHT JOIN rtree1 ON true INNER JOIN t3 ON (x NOTNULL)=+a;
60493c4087fSdan  } {}
60593c4087fSdan  do_execsql_test join8-18050 {
60693c4087fSdan    SELECT *, x NOTNULL, (x NOTNULL)=a FROM t2
60793c4087fSdan      RIGHT JOIN rtree1 ON true INNER JOIN t3 ON (x NOTNULL)=a;
60893c4087fSdan  } {}
60993c4087fSdan}
61093c4087fSdan
61193c4087fSdan
61293c4087fSdanreset_db
61393c4087fSdando_execsql_test join8-19000 {
61493c4087fSdan  CREATE TABLE t1(a INT);
61593c4087fSdan  CREATE TABLE t2(b INT, c INT);
61693c4087fSdan  CREATE TABLE t3(d INT);
61793c4087fSdan
61893c4087fSdan  INSERT INTO t1 VALUES(10);
61993c4087fSdan  INSERT INTO t2 VALUES(50,51);
62093c4087fSdan  INSERT INTO t3 VALUES(299);
62193c4087fSdan
62293c4087fSdan  CREATE INDEX t2b ON t2( (b IS NOT NULL) );
62393c4087fSdan}
62493c4087fSdan
62593c4087fSdando_execsql_test join8-19010 {
62693c4087fSdan  SELECT * FROM t1 LEFT JOIN t2 ON true INNER JOIN t3 ON (b IS NOT NULL)=0;
62793c4087fSdan}
62893c4087fSdan
629bb136903Sdrh# 2022-06-07
630bb136903Sdrh# https://sqlite.org/forum/forumpost/323f86cc30
631bb136903Sdrhreset_db
632bb136903Sdrhdo_execsql_test join8-20000 {
633bb136903Sdrh  CREATE TABLE t1(x TEXT);
634bb136903Sdrh  INSERT INTO t1(x) VALUES('aaa');
635bb136903Sdrh  CREATE VIEW v0(y) AS SELECT x FROM t1;
636bb136903Sdrh  CREATE TABLE t2(z TEXT);
637bb136903Sdrh} {}
638bb136903Sdrhdb null -
639bb136903Sdrhdo_execsql_test join8-20010 {
640bb136903Sdrh  SELECT * FROM t2 JOIN v0 ON z<>'bbb' RIGHT JOIN t1 ON z<>'ccc';
641bb136903Sdrh} {- - aaa}
642bb136903Sdrhdo_execsql_test join8-20020 {
643bb136903Sdrh  SELECT * FROM t2 JOIN v0 ON z<>'bbb' RIGHT JOIN t1 ON z<>'ccc' ORDER BY z;
644bb136903Sdrh} {- - aaa}
645bb136903Sdrhdo_execsql_test join8-20030 {
646bb136903Sdrh  SELECT 99 as "m" FROM t2 JOIN v0 ON z<>'bbb' RIGHT JOIN t1 ON z<>'ccc';
647bb136903Sdrh} {99}
648bb136903Sdrhdo_execsql_test join8-20040 {
649bb136903Sdrh  SELECT 99 as "m" FROM t2 JOIN v0 ON z<>'bbb' RIGHT JOIN t1 ON z<>'ccc' ORDER BY z;
650bb136903Sdrh} {99}
651bb136903Sdrhdo_execsql_test join8-20050 {
652bb136903Sdrh  SELECT count(*)
653bb136903Sdrh    FROM (SELECT 99 as "m" FROM t2 JOIN v0 ON z<>'' RIGHT JOIN t1 ON z<>'') AS "t3";
654bb136903Sdrh} {1}
655bb136903Sdrhdo_execsql_test join8-20060 {
656bb136903Sdrh  SELECT count(*)
657bb136903Sdrh    FROM (SELECT 99 as "m" FROM t2 JOIN v0 ON z<>'' RIGHT JOIN t1 ON z<>'' ORDER BY z) AS "t3";
658bb136903Sdrh} {1}
659bb136903Sdrh
660958fcd41Sdrh# 2022-06-10
661958fcd41Sdrh# https://sqlite.org/forum/forumpost/8e4c352937e82929
662958fcd41Sdrh#
663958fcd41Sdrh# Do not allow constant propagation between ON and WHERE clause terms.
664ae8776e0Sdrh# (Updated 2022-06-20) See also https://sqlite.org/forum/forumpost/57bdf2217d
665958fcd41Sdrh#
666958fcd41Sdrhreset_db
667958fcd41Sdrhdo_execsql_test join8-21000 {
668958fcd41Sdrh  CREATE TABLE t1(a INT,b BOOLEAN);
669958fcd41Sdrh  CREATE TABLE t2(c INT);  INSERT INTO t2 VALUES(NULL);
670958fcd41Sdrh  CREATE TABLE t3(d INT);
671958fcd41Sdrh}
672958fcd41Sdrhdo_execsql_test join8-21010 {
673958fcd41Sdrh  SELECT (b IS TRUE) FROM t1 JOIN t3 ON (b=TRUE) RIGHT JOIN t2 ON TRUE;
674958fcd41Sdrh} {0}
675958fcd41Sdrhdo_execsql_test join8-22020 {
676958fcd41Sdrh  SELECT * FROM t1 JOIN t3 ON (b=TRUE) RIGHT JOIN t2 ON TRUE WHERE (b IS TRUE);
677958fcd41Sdrh} {}
678ae8776e0Sdrhdo_execsql_test join8-22030 {
679ae8776e0Sdrh  DROP TABLE t1;
680ae8776e0Sdrh  DROP TABLE t2;
681ae8776e0Sdrh  DROP TABLE t3;
682ae8776e0Sdrh  CREATE TABLE t1(a INT);
683ae8776e0Sdrh  CREATE TABLE t2(b INT);
684ae8776e0Sdrh  CREATE TABLE t3(c INTEGER PRIMARY KEY, d INT);
685ae8776e0Sdrh  CREATE INDEX t3d ON t3(d);
686ae8776e0Sdrh  INSERT INTO t3 VALUES(0, 0);
687d7480403Sdrh}
688d7480403Sdrhdo_catchsql_test join8-22031 {
689ae8776e0Sdrh  SELECT * FROM t1 JOIN t2 ON d>b RIGHT JOIN t3 ON true WHERE +d = 0;
690d7480403Sdrh} {1 {ON clause references tables to its right}}
691d7480403Sdrhdo_catchsql_test join8-22040 {
692ae8776e0Sdrh  SELECT * FROM t1 JOIN t2 ON d>b RIGHT JOIN t3 ON true WHERE d = 0;
693d7480403Sdrh} {1 {ON clause references tables to its right}}
694ae8776e0Sdrh
6951cc5c4acSdrh
6961cc5c4acSdrh# 2022-06-10
6971cc5c4acSdrh# https://sqlite.org/forum/forumpost/51e6959f61
6981cc5c4acSdrh#
6991cc5c4acSdrh# Restrictions on the usage of WHERE clause constraints by joins that are
7001cc5c4acSdrh# involved with a RIGHT JOIN must also be applied to automatic indexes.
7011cc5c4acSdrh#
7021cc5c4acSdrhreset_db
7031cc5c4acSdrhdo_execsql_test join8-22000 {
7041cc5c4acSdrh  CREATE TABLE t1(a INT);
7051cc5c4acSdrh  CREATE TABLE t2(b INT);
7061cc5c4acSdrh  CREATE TABLE t3(c TEXT);  INSERT INTO t3 VALUES('x');
7071cc5c4acSdrh  CREATE TABLE t4(d TEXT);  INSERT INTO t4 VALUES('y');
7081cc5c4acSdrh  SELECT 99
7091cc5c4acSdrh    FROM t1
7101cc5c4acSdrh         LEFT JOIN t2 ON true
7111cc5c4acSdrh         RIGHT JOIN t3 ON true
7121cc5c4acSdrh         RIGHT JOIN t4 ON true
7131cc5c4acSdrh   WHERE a=b;
7141cc5c4acSdrh} {}
715958fcd41Sdrh
71692d1afbaSdrh# 2022-06-13
71792d1afbaSdrh# https://sqlite.org/forum/forumpost/b40696f501
71892d1afbaSdrh#
71992d1afbaSdrh# This optimization that converts "x ISNULL" into "FALSE" when column "x" has a
72092d1afbaSdrh# NOT NULL constraint is too aggresive if the query contains RIGHT JOIN.
72192d1afbaSdrh#
72292d1afbaSdrhreset_db
72392d1afbaSdrhdb null -
72492d1afbaSdrhdo_execsql_test join8-23000 {
72592d1afbaSdrh  CREATE TABLE t1(a TEXT);
72692d1afbaSdrh  INSERT INTO t1 VALUES('c');
72792d1afbaSdrh  CREATE TABLE t2(b TEXT, c TEXT NOT NULL);
72892d1afbaSdrh  INSERT INTO t2 VALUES('a', 'b');
72992d1afbaSdrh  CREATE TABLE t3(d TEXT);
73092d1afbaSdrh  INSERT INTO t3 VALUES('x');
73192d1afbaSdrh  CREATE TABLE t4(e TEXT);
73292d1afbaSdrh  INSERT INTO t4 VALUES('y');
73392d1afbaSdrh}
73492d1afbaSdrhdo_execsql_test join8-23010 {
73592d1afbaSdrh  SELECT *
73692d1afbaSdrh    FROM t1
73792d1afbaSdrh         LEFT JOIN t2 ON TRUE
73892d1afbaSdrh         JOIN t3 ON c=''
73992d1afbaSdrh         RIGHT JOIN t4 ON b='';
74092d1afbaSdrh} {- - - - y}
74192d1afbaSdrhdo_execsql_test join8-23020 {
74292d1afbaSdrh  SELECT *
74392d1afbaSdrh    FROM t1
74492d1afbaSdrh         LEFT JOIN t2 ON TRUE
74592d1afbaSdrh         JOIN t3 ON c=''
74692d1afbaSdrh         RIGHT JOIN t4 ON b=''
74792d1afbaSdrh   WHERE d ISNULL
74892d1afbaSdrh} {- - - - y}
749958fcd41Sdrh
75027a242c6Sdrh# 2022-06-14
75127a242c6Sdrh# dbsqlfuzz 2f3101834d14325a976f601b9267a0fd323d6bbd
75227a242c6Sdrh#
75327a242c6Sdrh# When the OP_NullRow opcode creates a new cursor, it must
75427a242c6Sdrh# set the cursor to no-reuse so that an OP_OpenEphemeral in
75527a242c6Sdrh# a subroutine does not try to reuse it.
75627a242c6Sdrh#
75727a242c6Sdrhreset_db
75827a242c6Sdrhdb null -
75927a242c6Sdrhdo_execsql_test join8-24000 {
76027a242c6Sdrh  CREATE TABLE t4(b INT, c INT);
76127a242c6Sdrh  CREATE TABLE t5(a INT, f INT);
76227a242c6Sdrh  INSERT INTO t5 VALUES(1,2);
76327a242c6Sdrh  WITH t7(x, y) AS (SELECT 100, 200 FROM t5)
76427a242c6Sdrh    SELECT * FROM t4 JOIN t7 ON true RIGHT JOIN (SELECT y AS z FROM t7) AS t6 ON (x=z);
76527a242c6Sdrh} {- - - - 200}
76627a242c6Sdrh
767436c28a2Sdrh# 2022-06-20
768436c28a2Sdrh# forum/forumpost/6650cd40b5634f35
769436c28a2Sdrh#
770436c28a2Sdrhreset_db
771436c28a2Sdrhdo_execsql_test join8-25000 {
772436c28a2Sdrh  CREATE TABLE t1(a1 INT);
773436c28a2Sdrh  CREATE TABLE t2(b2 INT);
774436c28a2Sdrh  CREATE TABLE t3(c3 INT, d3 INT UNIQUE);
775436c28a2Sdrh  CREATE TABLE t4(e4 INT, f4 TEXT);
776436c28a2Sdrh  INSERT INTO t3(c3, d3) VALUES (2, 1);
777436c28a2Sdrh  INSERT INTO t4(f4) VALUES ('x');
778436c28a2Sdrh  CREATE INDEX i0 ON t3(c3) WHERE d3 ISNULL;
779436c28a2Sdrh  ANALYZE main;
780436c28a2Sdrh}
781436c28a2Sdrhdb null -
782436c28a2Sdrhdo_execsql_test join8-25010 {
783436c28a2Sdrh  SELECT * FROM t1 LEFT JOIN t2 ON true JOIN t3 ON (b2 IN (a1)) FULL JOIN t4 ON true;
784436c28a2Sdrh} {- - - - - x}
785436c28a2Sdrhdo_execsql_test join8-25020 {
786436c28a2Sdrh  SELECT 1 FROM t1 LEFT JOIN t2 ON true JOIN t3 ON (b2 IN (a1)) FULL JOIN t4 ON true;
787436c28a2Sdrh} {1}
78827a242c6Sdrh
789*b88bf865Sdrh# 2022-07-13
790*b88bf865Sdrh# forum/forumpost/174afeae57
791*b88bf865Sdrh#
792*b88bf865Sdrhreset_db
793*b88bf865Sdrhdb null -
794*b88bf865Sdrhdo_execsql_test join8-26000 {
795*b88bf865Sdrh  CREATE TABLE t1(a INT);
796*b88bf865Sdrh  CREATE TABLE t2(b INT, c INT);
797*b88bf865Sdrh  CREATE VIEW t3(d) AS SELECT NULL FROM t2 FULL OUTER JOIN t1 ON c=a UNION ALL SELECT b FROM t2;
798*b88bf865Sdrh  INSERT INTO t1(a) VALUES (NULL);
799*b88bf865Sdrh  INSERT INTO t2(b, c) VALUES (99, NULL);
800*b88bf865Sdrh  SELECT DISTINCT b, c, d FROM t2, t3 WHERE b<>0
801*b88bf865Sdrh   UNION SELECT DISTINCT b, c, d FROM t2, t3 WHERE b ISNULL;
802*b88bf865Sdrh} {99 - - 99 - 99}
803*b88bf865Sdrh
804f7309bceSdrhfinish_test
805