2022-04-09 23:11:05 +03:00
|
|
|
# 2022-04-09
|
|
|
|
#
|
|
|
|
# The author disclaims copyright to this source code. In place of
|
|
|
|
# a legal notice, here is a blessing:
|
|
|
|
#
|
|
|
|
# May you do good and not evil.
|
|
|
|
# May you find forgiveness for yourself and forgive others.
|
|
|
|
# May you share freely, never taking more than you give.
|
|
|
|
#
|
|
|
|
#***********************************************************************
|
|
|
|
# This file implements regression tests for SQLite library.
|
|
|
|
#
|
|
|
|
# This file implements tests for RIGHT and FULL OUTER JOINs.
|
|
|
|
|
|
|
|
set testdir [file dirname $argv0]
|
|
|
|
source $testdir/tester.tcl
|
|
|
|
|
2022-04-11 02:01:20 +03:00
|
|
|
foreach {id schema} {
|
|
|
|
1 {
|
|
|
|
CREATE TABLE t1(a INT, b INT);
|
|
|
|
INSERT INTO t1 VALUES(1,2),(1,3),(1,4);
|
|
|
|
CREATE INDEX t1a ON t1(a);
|
|
|
|
CREATE TABLE t2(c INT, d INT);
|
|
|
|
INSERT INTO t2 VALUES(3,33),(4,44),(5,55);
|
|
|
|
CREATE INDEX t2c ON t2(c);
|
|
|
|
CREATE VIEW dual(dummy) AS VALUES('x');
|
|
|
|
}
|
|
|
|
2 {
|
|
|
|
CREATE TABLE t1(a INT, b INT);
|
|
|
|
INSERT INTO t1 VALUES(1,2),(1,3),(1,4);
|
|
|
|
CREATE INDEX t1ab ON t1(a,b);
|
|
|
|
CREATE TABLE t2(c INT, d INT);
|
|
|
|
INSERT INTO t2 VALUES(3,33),(4,44),(5,55);
|
|
|
|
CREATE INDEX t2cd ON t2(c,d);
|
|
|
|
CREATE VIEW dual(dummy) AS VALUES('x');
|
|
|
|
}
|
|
|
|
3 {
|
|
|
|
CREATE TABLE t1(a INT, b INT);
|
|
|
|
INSERT INTO t1 VALUES(1,2),(1,3),(1,4);
|
|
|
|
CREATE INDEX t1a ON t1(a);
|
|
|
|
CREATE TABLE t2(c INT, d INT PRIMARY KEY) WITHOUT ROWID;
|
|
|
|
INSERT INTO t2 VALUES(3,33),(4,44),(5,55);
|
|
|
|
CREATE INDEX t2c ON t2(c);
|
|
|
|
CREATE VIEW dual(dummy) AS VALUES('x');
|
|
|
|
}
|
|
|
|
4 {
|
|
|
|
CREATE TABLE t1(a INT, b INT);
|
|
|
|
INSERT INTO t1 VALUES(1,2),(1,3),(1,4);
|
|
|
|
CREATE TABLE t2(c INTEGER PRIMARY KEY, d INT);
|
|
|
|
INSERT INTO t2 VALUES(3,33),(4,44),(5,55);
|
|
|
|
CREATE VIEW dual(dummy) AS VALUES('x');
|
|
|
|
}
|
|
|
|
5 {
|
|
|
|
CREATE TABLE t1(a INT, b INT);
|
|
|
|
INSERT INTO t1 VALUES(1,2),(1,3),(1,4);
|
|
|
|
CREATE TABLE t2(c INT PRIMARY KEY, d INT) WITHOUT ROWID;
|
|
|
|
INSERT INTO t2 VALUES(3,33),(4,44),(5,55);
|
|
|
|
CREATE VIEW dual(dummy) AS VALUES('x');
|
|
|
|
}
|
|
|
|
6 {
|
|
|
|
CREATE TABLE t1(a INT, b INT);
|
|
|
|
INSERT INTO t1 VALUES(1,2),(1,3),(1,4);
|
|
|
|
CREATE VIEW t2(c,d) AS VALUES(3,33),(4,44),(5,55);
|
|
|
|
CREATE VIEW dual(dummy) AS VALUES('x');
|
|
|
|
}
|
|
|
|
7 {
|
|
|
|
CREATE VIEW t1(a,b) AS VALUES(1,2),(1,3),(1,4);
|
|
|
|
CREATE TABLE t2(c INTEGER PRIMARY KEY, d INT);
|
|
|
|
INSERT INTO t2 VALUES(3,33),(4,44),(5,55);
|
|
|
|
CREATE VIEW dual(dummy) AS VALUES('x');
|
|
|
|
}
|
2022-04-11 02:48:47 +03:00
|
|
|
8 {
|
|
|
|
CREATE TABLE t1(a INT, b INT);
|
|
|
|
INSERT INTO t1 VALUES(1,2),(1,3),(1,4);
|
|
|
|
CREATE TABLE t2(c INT, d INT);
|
|
|
|
INSERT INTO t2 VALUES(3,33),(4,44),(5,55);
|
|
|
|
CREATE VIEW dual(dummy) AS VALUES('x');
|
|
|
|
}
|
2022-04-10 19:13:37 +03:00
|
|
|
} {
|
2022-04-11 02:01:20 +03:00
|
|
|
reset_db
|
|
|
|
db nullvalue NULL
|
2022-04-11 02:48:47 +03:00
|
|
|
do_execsql_test join7-$id.setup $schema {}
|
2022-04-11 02:01:20 +03:00
|
|
|
do_execsql_test join7-$id.1 {
|
|
|
|
SELECT b, d FROM t1 FULL OUTER JOIN t2 ON b=c ORDER BY +b;
|
|
|
|
} {
|
|
|
|
NULL 55
|
|
|
|
2 NULL
|
|
|
|
3 33
|
|
|
|
4 44
|
|
|
|
}
|
|
|
|
do_execsql_test join7-$id.2 {
|
|
|
|
SELECT a, c FROM t1 FULL OUTER JOIN t2 ON b=c ORDER BY +b;
|
|
|
|
} {
|
|
|
|
NULL 5
|
|
|
|
1 NULL
|
|
|
|
1 3
|
|
|
|
1 4
|
|
|
|
}
|
|
|
|
do_execsql_test join7-$id.3 {
|
|
|
|
SELECT * FROM t1 FULL OUTER JOIN t2 ON b=c ORDER BY +b;
|
|
|
|
} {
|
|
|
|
NULL NULL 5 55
|
|
|
|
1 2 NULL NULL
|
|
|
|
1 3 3 33
|
|
|
|
1 4 4 44
|
|
|
|
}
|
|
|
|
do_execsql_test join7-$id.4 {
|
|
|
|
SELECT * FROM t1 RIGHT OUTER JOIN t2 ON b=c ORDER BY +b;
|
|
|
|
} {
|
|
|
|
NULL NULL 5 55
|
|
|
|
1 3 3 33
|
|
|
|
1 4 4 44
|
|
|
|
}
|
|
|
|
do_execsql_test join7-$id.5 {
|
|
|
|
SELECT * FROM dual JOIN t1 ON true RIGHT OUTER JOIN t2 ON b=c ORDER BY +b;
|
|
|
|
} {
|
|
|
|
NULL NULL NULL 5 55
|
|
|
|
x 1 3 3 33
|
|
|
|
x 1 4 4 44
|
|
|
|
}
|
|
|
|
do_execsql_test join7-$id.6 {
|
|
|
|
SELECT * FROM dual CROSS JOIN t1 RIGHT OUTER JOIN t2 ON b=c ORDER BY +b;
|
|
|
|
} {
|
|
|
|
NULL NULL NULL 5 55
|
|
|
|
x 1 3 3 33
|
|
|
|
x 1 4 4 44
|
|
|
|
}
|
|
|
|
do_execsql_test join7-$id.7 {
|
|
|
|
SELECT * FROM t1 LEFT OUTER JOIN t2 ON b=c ORDER BY +b;
|
|
|
|
} {
|
|
|
|
1 2 NULL NULL
|
|
|
|
1 3 3 33
|
|
|
|
1 4 4 44
|
|
|
|
}
|
|
|
|
do_execsql_test join7-$id.8 {
|
|
|
|
SELECT * FROM t1 FULL OUTER JOIN t2 ON b=c AND a=1 ORDER BY +b;
|
|
|
|
} {
|
|
|
|
NULL NULL 5 55
|
|
|
|
1 2 NULL NULL
|
|
|
|
1 3 3 33
|
|
|
|
1 4 4 44
|
|
|
|
}
|
|
|
|
do_execsql_test join7-$id.9 {
|
|
|
|
SELECT * FROM t1 FULL OUTER JOIN t2 ON b=c WHERE a=1 ORDER BY +b;
|
|
|
|
} {
|
|
|
|
1 2 NULL NULL
|
|
|
|
1 3 3 33
|
|
|
|
1 4 4 44
|
|
|
|
}
|
|
|
|
do_execsql_test join7-$id.10 {
|
|
|
|
SELECT * FROM t1 FULL OUTER JOIN t2 ON b=c WHERE a IS NULL ORDER BY +d;
|
|
|
|
} {
|
|
|
|
NULL NULL 3 33
|
|
|
|
NULL NULL 4 44
|
|
|
|
NULL NULL 5 55
|
|
|
|
}
|
|
|
|
do_execsql_test join7-$id.11 {
|
|
|
|
SELECT * FROM t1 FULL OUTER JOIN t2 ON b=c AND d<=0 ORDER BY +b, +d;
|
|
|
|
} {
|
|
|
|
NULL NULL 3 33
|
|
|
|
NULL NULL 4 44
|
|
|
|
NULL NULL 5 55
|
|
|
|
1 2 NULL NULL
|
|
|
|
1 3 NULL NULL
|
|
|
|
1 4 NULL NULL
|
|
|
|
}
|
|
|
|
}
|
2022-04-09 23:11:05 +03:00
|
|
|
finish_test
|