xref: /sqlite-3.40.0/test/join7.test (revision c7fc08f6)
1ac8c438aSdrh# 2022-04-09
2ac8c438aSdrh#
3ac8c438aSdrh# The author disclaims copyright to this source code.  In place of
4ac8c438aSdrh# a legal notice, here is a blessing:
5ac8c438aSdrh#
6ac8c438aSdrh#    May you do good and not evil.
7ac8c438aSdrh#    May you find forgiveness for yourself and forgive others.
8ac8c438aSdrh#    May you share freely, never taking more than you give.
9ac8c438aSdrh#
10ac8c438aSdrh#***********************************************************************
11ac8c438aSdrh# This file implements regression tests for SQLite library.
12ac8c438aSdrh#
13ac8c438aSdrh# This file implements tests for RIGHT and FULL OUTER JOINs.
14ac8c438aSdrh
15ac8c438aSdrhset testdir [file dirname $argv0]
16ac8c438aSdrhsource $testdir/tester.tcl
17ac8c438aSdrh
189debb58eSdrhforeach {id schema} {
199debb58eSdrh  1 {
209debb58eSdrh    CREATE TABLE t1(a INT, b INT);
21ac8c438aSdrh    INSERT INTO t1 VALUES(1,2),(1,3),(1,4);
22ac8c438aSdrh    CREATE INDEX t1a ON t1(a);
239debb58eSdrh    CREATE TABLE t2(c INT, d INT);
24ac8c438aSdrh    INSERT INTO t2 VALUES(3,33),(4,44),(5,55);
25ac8c438aSdrh    CREATE INDEX t2c ON t2(c);
269debb58eSdrh    CREATE VIEW dual(dummy) AS VALUES('x');
279debb58eSdrh  }
289debb58eSdrh  2 {
299debb58eSdrh    CREATE TABLE t1(a INT, b INT);
309debb58eSdrh    INSERT INTO t1 VALUES(1,2),(1,3),(1,4);
319debb58eSdrh    CREATE INDEX t1ab ON t1(a,b);
329debb58eSdrh    CREATE TABLE t2(c INT, d INT);
339debb58eSdrh    INSERT INTO t2 VALUES(3,33),(4,44),(5,55);
349debb58eSdrh    CREATE INDEX t2cd ON t2(c,d);
359debb58eSdrh    CREATE VIEW dual(dummy) AS VALUES('x');
369debb58eSdrh  }
379debb58eSdrh  3 {
389debb58eSdrh    CREATE TABLE t1(a INT, b INT);
399debb58eSdrh    INSERT INTO t1 VALUES(1,2),(1,3),(1,4);
409debb58eSdrh    CREATE INDEX t1a ON t1(a);
419debb58eSdrh    CREATE TABLE t2(c INT, d INT PRIMARY KEY) WITHOUT ROWID;
429debb58eSdrh    INSERT INTO t2 VALUES(3,33),(4,44),(5,55);
439debb58eSdrh    CREATE INDEX t2c ON t2(c);
449debb58eSdrh    CREATE VIEW dual(dummy) AS VALUES('x');
459debb58eSdrh  }
469debb58eSdrh  4 {
479debb58eSdrh    CREATE TABLE t1(a INT, b INT);
489debb58eSdrh    INSERT INTO t1 VALUES(1,2),(1,3),(1,4);
499debb58eSdrh    CREATE TABLE t2(c INTEGER PRIMARY KEY, d INT);
509debb58eSdrh    INSERT INTO t2 VALUES(3,33),(4,44),(5,55);
519debb58eSdrh    CREATE VIEW dual(dummy) AS VALUES('x');
529debb58eSdrh  }
539debb58eSdrh  5 {
549debb58eSdrh    CREATE TABLE t1(a INT, b INT);
559debb58eSdrh    INSERT INTO t1 VALUES(1,2),(1,3),(1,4);
569debb58eSdrh    CREATE TABLE t2(c INT PRIMARY KEY, d INT) WITHOUT ROWID;
579debb58eSdrh    INSERT INTO t2 VALUES(3,33),(4,44),(5,55);
589debb58eSdrh    CREATE VIEW dual(dummy) AS VALUES('x');
599debb58eSdrh  }
609debb58eSdrh  6 {
619debb58eSdrh    CREATE TABLE t1(a INT, b INT);
629debb58eSdrh    INSERT INTO t1 VALUES(1,2),(1,3),(1,4);
639debb58eSdrh    CREATE VIEW t2(c,d) AS VALUES(3,33),(4,44),(5,55);
649debb58eSdrh    CREATE VIEW dual(dummy) AS VALUES('x');
659debb58eSdrh  }
669debb58eSdrh  7 {
679debb58eSdrh    CREATE VIEW t1(a,b) AS VALUES(1,2),(1,3),(1,4);
689debb58eSdrh    CREATE TABLE t2(c INTEGER PRIMARY KEY, d INT);
699debb58eSdrh    INSERT INTO t2 VALUES(3,33),(4,44),(5,55);
709debb58eSdrh    CREATE VIEW dual(dummy) AS VALUES('x');
719debb58eSdrh  }
72529394e5Sdrh  8 {
73529394e5Sdrh    CREATE TABLE t1(a INT, b INT);
74529394e5Sdrh    INSERT INTO t1 VALUES(1,2),(1,3),(1,4);
75529394e5Sdrh    CREATE TABLE t2(c INT, d INT);
76529394e5Sdrh    INSERT INTO t2 VALUES(3,33),(4,44),(5,55);
77529394e5Sdrh    CREATE VIEW dual(dummy) AS VALUES('x');
78529394e5Sdrh  }
7941798d5bSdrh  9 {
8041798d5bSdrh    CREATE TABLE t1(a INT, b INT);
8141798d5bSdrh    INSERT INTO t1 VALUES(1,2),(1,3),(1,4);
8241798d5bSdrh    CREATE TABLE t2a(c INTEGER PRIMARY KEY, i1 INT);
8341798d5bSdrh    CREATE TABLE t2b(i1 INTEGER PRIMARY KEY, d INT);
8441798d5bSdrh    CREATE VIEW t2(c,d) AS SELECT c, d FROM t2a NATURAL JOIN t2b;
8541798d5bSdrh    INSERT INTO t2a VALUES(3,93),(4,94),(5,95),(6,96),(7,97);
8641798d5bSdrh    INSERT INTO t2b VALUES(91,11),(92,22),(93,33),(94,44),(95,55);
8741798d5bSdrh    CREATE TABLE dual(dummy TEXT);
8841798d5bSdrh    INSERT INTO dual(dummy) VALUES('x');
8941798d5bSdrh  }
9037259f4eSdrh  10 {
9137259f4eSdrh    CREATE TABLE t1(a INT, b INT, PRIMARY KEY(a,b)) WITHOUT ROWID;
9237259f4eSdrh    INSERT INTO t1 VALUES(1,2),(1,3),(1,4);
9337259f4eSdrh    CREATE TABLE t2a(c INTEGER PRIMARY KEY, i1 INT);
9437259f4eSdrh    CREATE TABLE t2b(i1 INTEGER PRIMARY KEY, d INT);
9537259f4eSdrh    CREATE VIEW t2(c,d) AS SELECT c, d FROM t2a NATURAL JOIN t2b;
9637259f4eSdrh    INSERT INTO t2a VALUES(3,93),(4,94),(5,95),(6,96),(7,97);
9737259f4eSdrh    INSERT INTO t2b VALUES(91,11),(92,22),(93,33),(94,44),(95,55);
9837259f4eSdrh    CREATE TABLE dual(dummy TEXT);
9937259f4eSdrh    INSERT INTO dual(dummy) VALUES('x');
10037259f4eSdrh  }
1019debb58eSdrh} {
1029debb58eSdrh  reset_db
1039debb58eSdrh  db nullvalue NULL
104529394e5Sdrh  do_execsql_test join7-$id.setup $schema {}
1052e1bcc9dSdrh
1062e1bcc9dSdrh  # Verified against PG-14 for case 1
10737259f4eSdrh  do_execsql_test join7-$id.10 {
108fcde633fSdrh    SELECT b, d FROM t1 FULL OUTER JOIN t2 ON b=c ORDER BY +b;
109a20c71e9Sdrh  } {
110a20c71e9Sdrh    NULL 55
111a20c71e9Sdrh    2    NULL
112a20c71e9Sdrh    3    33
113a20c71e9Sdrh    4    44
114a20c71e9Sdrh  }
1152e1bcc9dSdrh
1162e1bcc9dSdrh  # Verified against PG-14 for case 1
11737259f4eSdrh  do_execsql_test join7-$id.20 {
118fcde633fSdrh    SELECT a, c FROM t1 FULL OUTER JOIN t2 ON b=c ORDER BY +b;
119a20c71e9Sdrh  } {
120a20c71e9Sdrh    NULL  5
121a20c71e9Sdrh    1     NULL
122a20c71e9Sdrh    1     3
123a20c71e9Sdrh    1     4
124a20c71e9Sdrh  }
1252e1bcc9dSdrh
12637259f4eSdrh  do_execsql_test join7-$id.30 {
127fcde633fSdrh    SELECT * FROM t1 FULL OUTER JOIN t2 ON b=c ORDER BY +b;
128a20c71e9Sdrh  } {
129a20c71e9Sdrh    NULL NULL 5    55
130a20c71e9Sdrh    1    2    NULL NULL
131a20c71e9Sdrh    1    3    3    33
132a20c71e9Sdrh    1    4    4    44
133a20c71e9Sdrh  }
13437259f4eSdrh  do_execsql_test join7-$id.31 {
13537259f4eSdrh    SELECT t1.*, t2.* FROM t2 FULL OUTER JOIN t1 ON b=c ORDER BY +b;
13637259f4eSdrh  } {
13737259f4eSdrh    NULL NULL 5    55
13837259f4eSdrh    1    2    NULL NULL
13937259f4eSdrh    1    3    3    33
14037259f4eSdrh    1    4    4    44
14137259f4eSdrh  }
142*c7fc08f6Sdrh  do_execsql_test join7-$id.32 {
143*c7fc08f6Sdrh    SELECT t1.*, t2.* FROM t2 FULL OUTER JOIN t1 ON b=c
144*c7fc08f6Sdrh     WHERE b=c
145*c7fc08f6Sdrh     ORDER BY +b;
146*c7fc08f6Sdrh  } {
147*c7fc08f6Sdrh    1    3    3    33
148*c7fc08f6Sdrh    1    4    4    44
149*c7fc08f6Sdrh  }
150*c7fc08f6Sdrh  do_execsql_test join7-$id.33 {
151*c7fc08f6Sdrh    SELECT t1.*, t2.* FROM t2 FULL OUTER JOIN t1 ON b=c
152*c7fc08f6Sdrh     WHERE b>0
153*c7fc08f6Sdrh     ORDER BY +b;
154*c7fc08f6Sdrh  } {
155*c7fc08f6Sdrh    1    2    NULL NULL
156*c7fc08f6Sdrh    1    3    3    33
157*c7fc08f6Sdrh    1    4    4    44
158*c7fc08f6Sdrh  }
159*c7fc08f6Sdrh  do_execsql_test join7-$id.34 {
160*c7fc08f6Sdrh    SELECT t1.*, t2.* FROM t2 FULL OUTER JOIN t1 ON b=c
161*c7fc08f6Sdrh     WHERE b>0 OR b IS NULL
162*c7fc08f6Sdrh     ORDER BY +b;
163*c7fc08f6Sdrh  } {
164*c7fc08f6Sdrh    NULL NULL 5    55
165*c7fc08f6Sdrh    1    2    NULL NULL
166*c7fc08f6Sdrh    1    3    3    33
167*c7fc08f6Sdrh    1    4    4    44
168*c7fc08f6Sdrh  }
169*c7fc08f6Sdrh  do_execsql_test join7-$id.35 {
170*c7fc08f6Sdrh    SELECT t1.*, t2.* FROM t2 FULL OUTER JOIN t1 ON b=c AND b>3 AND c>4
171*c7fc08f6Sdrh     ORDER BY coalesce(b,c,0);
172*c7fc08f6Sdrh  } {
173*c7fc08f6Sdrh    1    2    NULL NULL
174*c7fc08f6Sdrh    NULL NULL 3    33
175*c7fc08f6Sdrh    1    3    NULL NULL
176*c7fc08f6Sdrh    NULL NULL 4    44
177*c7fc08f6Sdrh    1    4    NULL NULL
178*c7fc08f6Sdrh    NULL NULL 5    55
179*c7fc08f6Sdrh  }
180*c7fc08f6Sdrh  do_execsql_test join7-$id.36 {
181*c7fc08f6Sdrh    SELECT t1.*, t2.* FROM t2 FULL OUTER JOIN t1 ON b=c AND b>3 WHERE c>4
182*c7fc08f6Sdrh     ORDER BY coalesce(b,c,0);
183*c7fc08f6Sdrh  } {
184*c7fc08f6Sdrh    NULL NULL 5    55
185*c7fc08f6Sdrh  }
186*c7fc08f6Sdrh  do_execsql_test join7-$id.37 {
187*c7fc08f6Sdrh    SELECT t1.*, t2.* FROM t2 FULL OUTER JOIN t1 ON b=c WHERE b>3 AND c>4
188*c7fc08f6Sdrh     ORDER BY coalesce(b,c,0);
189*c7fc08f6Sdrh  } {
190*c7fc08f6Sdrh  }
191*c7fc08f6Sdrh  do_execsql_test join7-$id.38 {
192*c7fc08f6Sdrh    SELECT t1.*, t2.* FROM t2 FULL OUTER JOIN t1 ON b=c WHERE b>3 OR c>4
193*c7fc08f6Sdrh     ORDER BY coalesce(b,c,0);
194*c7fc08f6Sdrh  } {
195*c7fc08f6Sdrh    1    4    4    44
196*c7fc08f6Sdrh    NULL NULL 5    55
197*c7fc08f6Sdrh  }
198*c7fc08f6Sdrh  do_execsql_test join7-$id.39 {
199*c7fc08f6Sdrh    SELECT t1.*, t2.* FROM t2 FULL OUTER JOIN t1 ON b=c AND (b>3 OR c>4)
200*c7fc08f6Sdrh     ORDER BY coalesce(b,c,0);
201*c7fc08f6Sdrh  } {
202*c7fc08f6Sdrh    1    2    NULL NULL
203*c7fc08f6Sdrh    NULL NULL 3    33
204*c7fc08f6Sdrh    1    3    NULL NULL
205*c7fc08f6Sdrh    1    4    4    44
206*c7fc08f6Sdrh    NULL NULL 5    55
207*c7fc08f6Sdrh  }
20837259f4eSdrh  do_execsql_test join7-$id.40 {
209fcde633fSdrh    SELECT * FROM t1 RIGHT OUTER JOIN t2 ON b=c ORDER BY +b;
210a20c71e9Sdrh  } {
211a20c71e9Sdrh    NULL NULL 5    55
212a20c71e9Sdrh    1    3    3    33
213a20c71e9Sdrh    1    4    4    44
214a20c71e9Sdrh  }
21537259f4eSdrh  do_execsql_test join7-$id.50 {
21637259f4eSdrh    SELECT t1.*, t2.* FROM t2 LEFT OUTER JOIN t1 ON b=c ORDER BY +b;
21737259f4eSdrh  } {
21837259f4eSdrh    NULL NULL 5    55
21937259f4eSdrh    1    3    3    33
22037259f4eSdrh    1    4    4    44
22137259f4eSdrh  }
22237259f4eSdrh  do_execsql_test join7-$id.60 {
223fcde633fSdrh    SELECT * FROM dual JOIN t1 ON true RIGHT OUTER JOIN t2 ON b=c ORDER BY +b;
224fcde633fSdrh  } {
225fcde633fSdrh    NULL NULL NULL 5    55
226fcde633fSdrh    x    1    3    3    33
227fcde633fSdrh    x    1    4    4    44
228fcde633fSdrh  }
22937259f4eSdrh  do_execsql_test join7-$id.70 {
23037259f4eSdrh    SELECT t1.*, t2.*
23137259f4eSdrh      FROM t2 LEFT JOIN (dual JOIN t1 ON true) ON b=c ORDER BY +b;
23237259f4eSdrh  } {
23337259f4eSdrh    NULL NULL 5    55
23437259f4eSdrh    1    3    3    33
23537259f4eSdrh    1    4    4    44
23637259f4eSdrh  }
23737259f4eSdrh  do_execsql_test join7-$id.80 {
238fcde633fSdrh    SELECT * FROM dual CROSS JOIN t1 RIGHT OUTER JOIN t2 ON b=c ORDER BY +b;
239fcde633fSdrh  } {
240fcde633fSdrh    NULL NULL NULL 5    55
241fcde633fSdrh    x    1    3    3    33
242fcde633fSdrh    x    1    4    4    44
243fcde633fSdrh  }
24437259f4eSdrh  do_execsql_test join7-$id.81 {
24537259f4eSdrh    SELECT dual.*, t1.*, t2.*
24637259f4eSdrh      FROM t1 CROSS JOIN dual RIGHT OUTER JOIN t2 ON b=c ORDER BY +b;
24737259f4eSdrh  } {
24837259f4eSdrh    NULL NULL NULL 5    55
24937259f4eSdrh    x    1    3    3    33
25037259f4eSdrh    x    1    4    4    44
25137259f4eSdrh  }
25237259f4eSdrh  do_execsql_test join7-$id.90 {
253fcde633fSdrh    SELECT * FROM t1 LEFT OUTER JOIN t2 ON b=c ORDER BY +b;
254a20c71e9Sdrh  } {
255a20c71e9Sdrh    1    2    NULL NULL
256a20c71e9Sdrh    1    3    3    33
257a20c71e9Sdrh    1    4    4    44
258a20c71e9Sdrh  }
25937259f4eSdrh  do_execsql_test join7-$id.100 {
260fcde633fSdrh    SELECT * FROM t1 FULL OUTER JOIN t2 ON b=c AND a=1 ORDER BY +b;
261e21e36ddSdrh  } {
262e21e36ddSdrh    NULL NULL 5    55
263e21e36ddSdrh    1    2    NULL NULL
264e21e36ddSdrh    1    3    3    33
265e21e36ddSdrh    1    4    4    44
266e21e36ddSdrh  }
26737259f4eSdrh  do_execsql_test join7-$id.101 {
26837259f4eSdrh    SELECT t1.*, t2.* FROM t2 FULL OUTER JOIN t1 ON b=c AND a=1 ORDER BY +b;
26937259f4eSdrh  } {
27037259f4eSdrh    NULL NULL 5    55
27137259f4eSdrh    1    2    NULL NULL
27237259f4eSdrh    1    3    3    33
27337259f4eSdrh    1    4    4    44
27437259f4eSdrh  }
2752e1bcc9dSdrh
2762e1bcc9dSdrh  # Verified against PG-14 for case 1
27737259f4eSdrh  do_execsql_test join7-$id.110 {
278fcde633fSdrh    SELECT * FROM t1 FULL OUTER JOIN t2 ON b=c WHERE a=1 ORDER BY +b;
279e21e36ddSdrh  } {
280e21e36ddSdrh    1    2    NULL NULL
281e21e36ddSdrh    1    3    3    33
282e21e36ddSdrh    1    4    4    44
283e21e36ddSdrh  }
2842e1bcc9dSdrh
285ff02ac7fSdrh  do_execsql_test join7-$id.111 {
286ff02ac7fSdrh    SELECT t1.*, t2.* FROM t2 FULL OUTER JOIN t1 ON b=c WHERE a=1 ORDER BY +b;
287ff02ac7fSdrh  } {
288ff02ac7fSdrh    1    2    NULL NULL
289ff02ac7fSdrh    1    3    3    33
290ff02ac7fSdrh    1    4    4    44
291ff02ac7fSdrh  }
2922e1bcc9dSdrh
2932e1bcc9dSdrh  # Verified against PG-14 for case 1
2946134b2dfSdrh  do_execsql_test join7-$id.115 {
2956134b2dfSdrh    SELECT * FROM t1 FULL OUTER JOIN t2 ON b=c
2966134b2dfSdrh     WHERE a=1 OR a IS NULL ORDER BY +b;
2976134b2dfSdrh  } {
2986134b2dfSdrh    NULL NULL 5    55
2996134b2dfSdrh    1    2    NULL NULL
3006134b2dfSdrh    1    3    3    33
3016134b2dfSdrh    1    4    4    44
3026134b2dfSdrh  }
3032e1bcc9dSdrh
3046134b2dfSdrh  do_execsql_test join7-$id.116 {
3056134b2dfSdrh    SELECT t1.*, t2.* FROM t2 FULL OUTER JOIN t1 ON b=c
3066134b2dfSdrh     WHERE a=1 OR a IS NULL ORDER BY +b;
3076134b2dfSdrh  } {
3086134b2dfSdrh    NULL NULL 5    55
3096134b2dfSdrh    1    2    NULL NULL
3106134b2dfSdrh    1    3    3    33
3116134b2dfSdrh    1    4    4    44
3126134b2dfSdrh  }
3132e1bcc9dSdrh
3142e1bcc9dSdrh  # Verified against PG-14 for case 1:
31537259f4eSdrh  do_execsql_test join7-$id.120 {
316fcde633fSdrh    SELECT * FROM t1 FULL OUTER JOIN t2 ON b=c WHERE a IS NULL ORDER BY +d;
317e21e36ddSdrh  } {
318e21e36ddSdrh    NULL NULL 5    55
319e21e36ddSdrh  }
3202e1bcc9dSdrh
3212e1bcc9dSdrh  # Verified against PG-14 for case 1:
32237259f4eSdrh  do_execsql_test join7-$id.130 {
323fcde633fSdrh    SELECT * FROM t1 FULL OUTER JOIN t2 ON b=c AND d<=0 ORDER BY +b, +d;
324e21e36ddSdrh  } {
325e21e36ddSdrh    NULL NULL 3    33
326e21e36ddSdrh    NULL NULL 4    44
327e21e36ddSdrh    NULL NULL 5    55
328e21e36ddSdrh    1    2    NULL NULL
329e21e36ddSdrh    1    3    NULL NULL
330e21e36ddSdrh    1    4    NULL NULL
331e21e36ddSdrh  }
3322e1bcc9dSdrh
3332e1bcc9dSdrh  # Verified against PG-14 for case 1:
33437259f4eSdrh  do_execsql_test join7-$id.140 {
3353a6e4c59Sdrh    SELECT a, b, c, d
3363a6e4c59Sdrh      FROM t2 FULL OUTER JOIN t1 ON b=c AND d<=0 ORDER BY +b, +d;
3373a6e4c59Sdrh  } {
3383a6e4c59Sdrh    NULL NULL 3    33
3393a6e4c59Sdrh    NULL NULL 4    44
3403a6e4c59Sdrh    NULL NULL 5    55
3413a6e4c59Sdrh    1    2    NULL NULL
3423a6e4c59Sdrh    1    3    NULL NULL
3433a6e4c59Sdrh    1    4    NULL NULL
3443a6e4c59Sdrh  }
3452e1bcc9dSdrh
3466134b2dfSdrh  do_execsql_test join7-$id.141 {
3476134b2dfSdrh    SELECT a, b, c, d
3486134b2dfSdrh      FROM t2 FULL OUTER JOIN t1 ON b=c AND d<=0
3496134b2dfSdrh     ORDER BY +b, +d LIMIT 2 OFFSET 2
3506134b2dfSdrh  } {
3516134b2dfSdrh    NULL NULL 5    55
3526134b2dfSdrh    1    2    NULL NULL
3536134b2dfSdrh  }
3549debb58eSdrh}
355ac8c438aSdrhfinish_test
356