211 lines
5.1 KiB
Plaintext
211 lines
5.1 KiB
Plaintext
# 2002 May 24
|
|
#
|
|
# 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 joins, including outer joins.
|
|
#
|
|
# $Id: join.test,v 1.2 2002/05/25 00:18:21 drh Exp $
|
|
|
|
set testdir [file dirname $argv0]
|
|
source $testdir/tester.tcl
|
|
|
|
do_test join-1.1 {
|
|
execsql {
|
|
CREATE TABLE t1(a,b,c);
|
|
INSERT INTO t1 VALUES(1,2,3);
|
|
INSERT INTO t1 VALUES(2,3,4);
|
|
INSERT INTO t1 VALUES(3,4,5);
|
|
SELECT * FROM t1;
|
|
}
|
|
} {1 2 3 2 3 4 3 4 5}
|
|
do_test join-1.2 {
|
|
execsql {
|
|
CREATE TABLE t2(b,c,d);
|
|
INSERT INTO t2 VALUES(1,2,3);
|
|
INSERT INTO t2 VALUES(2,3,4);
|
|
INSERT INTO t2 VALUES(3,4,5);
|
|
SELECT * FROM t2;
|
|
}
|
|
} {1 2 3 2 3 4 3 4 5}
|
|
|
|
do_test join-1.3 {
|
|
execsql2 {
|
|
SELECT * FROM t1 NATURAL JOIN t2;
|
|
}
|
|
} {t1.a 1 t1.b 2 t1.c 3 t2.d 4 t1.a 2 t1.b 3 t1.c 4 t2.d 5}
|
|
do_test join-1.3.1 {
|
|
execsql2 {
|
|
SELECT * FROM t2 NATURAL JOIN t1;
|
|
}
|
|
} {t2.b 2 t2.c 3 t2.d 4 t1.a 1 t2.b 3 t2.c 4 t2.d 5 t1.a 2}
|
|
do_test join-1.4 {
|
|
execsql2 {
|
|
SELECT * FROM t1 INNER JOIN t2 USING(b,c);
|
|
}
|
|
} {t1.a 1 t1.b 2 t1.c 3 t2.d 4 t1.a 2 t1.b 3 t1.c 4 t2.d 5}
|
|
do_test join-1.5 {
|
|
execsql2 {
|
|
SELECT * FROM t1 INNER JOIN t2 USING(b);
|
|
}
|
|
} {t1.a 1 t1.b 2 t1.c 3 t2.c 3 t2.d 4 t1.a 2 t1.b 3 t1.c 4 t2.c 4 t2.d 5}
|
|
do_test join-1.6 {
|
|
execsql2 {
|
|
SELECT * FROM t1 INNER JOIN t2 USING(c);
|
|
}
|
|
} {t1.a 1 t1.b 2 t1.c 3 t2.b 2 t2.d 4 t1.a 2 t1.b 3 t1.c 4 t2.b 3 t2.d 5}
|
|
do_test join-1.7 {
|
|
execsql2 {
|
|
SELECT * FROM t1 INNER JOIN t2 USING(c,b);
|
|
}
|
|
} {t1.a 1 t1.b 2 t1.c 3 t2.d 4 t1.a 2 t1.b 3 t1.c 4 t2.d 5}
|
|
|
|
do_test join-1.8 {
|
|
execsql {
|
|
SELECT * FROM t1 NATURAL CROSS JOIN t2;
|
|
}
|
|
} {1 2 3 4 2 3 4 5}
|
|
do_test join-1.9 {
|
|
execsql {
|
|
SELECT * FROM t1 CROSS JOIN t2 USING(b,c);
|
|
}
|
|
} {1 2 3 4 2 3 4 5}
|
|
do_test join-1.10 {
|
|
execsql {
|
|
SELECT * FROM t1 NATURAL INNER JOIN t2;
|
|
}
|
|
} {1 2 3 4 2 3 4 5}
|
|
do_test join-1.11 {
|
|
execsql {
|
|
SELECT * FROM t1 INNER JOIN t2 USING(b,c);
|
|
}
|
|
} {1 2 3 4 2 3 4 5}
|
|
do_test join-1.12 {
|
|
execsql {
|
|
SELECT * FROM t1 natural inner join t2;
|
|
}
|
|
} {1 2 3 4 2 3 4 5}
|
|
do_test join-1.13 {
|
|
execsql2 {
|
|
SELECT * FROM t1 NATURAL JOIN
|
|
(SELECT b as 'c', c as 'd', d as 'e' FROM t2) as t3
|
|
}
|
|
} {t1.a 1 t1.b 2 t1.c 3 t3.d 4 t3.e 5}
|
|
do_test join-1.14 {
|
|
execsql2 {
|
|
SELECT * FROM (SELECT b as 'c', c as 'd', d as 'e' FROM t2) as 'tx'
|
|
NATURAL JOIN t1
|
|
}
|
|
} {tx.c 3 tx.d 4 tx.e 5 t1.a 1 t1.b 2}
|
|
|
|
do_test join-1.15 {
|
|
execsql {
|
|
CREATE TABLE t3(c,d,e);
|
|
INSERT INTO t3 VALUES(2,3,4);
|
|
INSERT INTO t3 VALUES(3,4,5);
|
|
INSERT INTO t3 VALUES(4,5,6);
|
|
SELECT * FROM t3;
|
|
}
|
|
} {2 3 4 3 4 5 4 5 6}
|
|
do_test join-1.16 {
|
|
execsql {
|
|
SELECT * FROM t1 natural join t2 natural join t3;
|
|
}
|
|
} {1 2 3 4 5 2 3 4 5 6}
|
|
do_test join-1.17 {
|
|
execsql2 {
|
|
SELECT * FROM t1 natural join t2 natural join t3;
|
|
}
|
|
} {t1.a 1 t1.b 2 t1.c 3 t2.d 4 t3.e 5 t1.a 2 t1.b 3 t1.c 4 t2.d 5 t3.e 6}
|
|
do_test join-1.18 {
|
|
execsql {
|
|
CREATE TABLE t4(d,e,f);
|
|
INSERT INTO t4 VALUES(2,3,4);
|
|
INSERT INTO t4 VALUES(3,4,5);
|
|
INSERT INTO t4 VALUES(4,5,6);
|
|
SELECT * FROM t4;
|
|
}
|
|
} {2 3 4 3 4 5 4 5 6}
|
|
do_test join-1.19 {
|
|
execsql {
|
|
SELECT * FROM t1 natural join t2 natural join t4;
|
|
}
|
|
} {1 2 3 4 5 6}
|
|
do_test join-1.19 {
|
|
execsql2 {
|
|
SELECT * FROM t1 natural join t2 natural join t4;
|
|
}
|
|
} {t1.a 1 t1.b 2 t1.c 3 t2.d 4 t4.e 5 t4.f 6}
|
|
do_test join-1.20 {
|
|
execsql {
|
|
SELECT * FROM t1 natural join t2 natural join t3 WHERE t1.a=1
|
|
}
|
|
} {1 2 3 4 5}
|
|
|
|
do_test join-2.1 {
|
|
execsql {
|
|
SELECT * FROM t1 NATURAL LEFT JOIN t2;
|
|
}
|
|
} {1 2 3 4 2 3 4 5 3 4 5 {}}
|
|
do_test join-2.2 {
|
|
execsql {
|
|
SELECT * FROM t2 NATURAL LEFT OUTER JOIN t1;
|
|
}
|
|
} {1 2 3 {} 2 3 4 1 3 4 5 2}
|
|
do_test join-2.3 {
|
|
catchsql {
|
|
SELECT * FROM t1 NATURAL RIGHT OUTER JOIN t2;
|
|
}
|
|
} {1 {RIGHT and FULL OUTER JOINs are not currently supported}}
|
|
|
|
do_test join-3.1 {
|
|
catchsql {
|
|
SELECT * FROM t1 NATURAL JOIN t2 ON t1.a=t2.b;
|
|
}
|
|
} {1 {a NATURAL join may not have an ON or USING clause}}
|
|
do_test join-3.2 {
|
|
catchsql {
|
|
SELECT * FROM t1 NATURAL JOIN t2 USING(b);
|
|
}
|
|
} {1 {a NATURAL join may not have an ON or USING clause}}
|
|
do_test join-3.3 {
|
|
catchsql {
|
|
SELECT * FROM t1 JOIN t2 ON t1.a=t2.b USING(b);
|
|
}
|
|
} {1 {cannot have both ON and USING clauses in the same join}}
|
|
do_test join-3.4 {
|
|
catchsql {
|
|
SELECT * FROM t1 JOIN t2 USING(a);
|
|
}
|
|
} {1 {cannot join using column a - column not present in both tables}}
|
|
do_test join-3.5 {
|
|
catchsql {
|
|
SELECT * FROM t1 USING(a);
|
|
}
|
|
} {0 {1 2 3 2 3 4 3 4 5}}
|
|
do_test join-3.6 {
|
|
catchsql {
|
|
SELECT * FROM t1 JOIN t2 ON t3.a=t2.b;
|
|
}
|
|
} {1 {no such column: t3.a}}
|
|
do_test join-3.7 {
|
|
catchsql {
|
|
SELECT * FROM t1 INNER OUTER JOIN t2;
|
|
}
|
|
} {1 {unknown or unsupported join type: INNER OUTER}}
|
|
do_test join-3.7 {
|
|
catchsql {
|
|
SELECT * FROM t1 BOGUS JOIN t2;
|
|
}
|
|
} {1 {unknown or unsupported join type: BOGUS}}
|
|
|
|
|
|
finish_test
|