3 # The author disclaims copyright to this source code. In place of
4 # a legal notice, here is a blessing:
6 # May you do good and not evil.
7 # May you find forgiveness for yourself and forgive others.
8 # May you share freely, never taking more than you give.
10 #***********************************************************************
11 # This file implements regression tests for SQLite library.
13 # This file implements tests for joins, including outer joins.
15 # $Id: join.test,v 1.27 2009/07/01 16:12:08 danielk1977 Exp $
17 set testdir [file dirname $argv0]
18 source $testdir/tester.tcl
22 CREATE TABLE t1(a,b,c);
23 INSERT INTO t1 VALUES(1,2,3);
24 INSERT INTO t1 VALUES(2,3,4);
25 INSERT INTO t1 VALUES(3,4,5);
31 CREATE TABLE t2(b,c,d);
32 INSERT INTO t2 VALUES(1,2,3);
33 INSERT INTO t2 VALUES(2,3,4);
34 INSERT INTO t2 VALUES(3,4,5);
39 # A FROM clause of the form: "<table>, <table> ON <expr>" is not
40 # allowed by the SQLite syntax diagram, nor by any other SQL database
41 # engine that we are aware of. Nevertheless, historic versions of
42 # SQLite have allowed it. We need to continue to support it moving
43 # forward to prevent breakage of legacy applications. Though, we will
44 # not advertise it as being supported.
46 do_execsql_test join-1.2.1 {
47 SELECT t1.rowid, t2.rowid, '|' FROM t1, t2 ON t1.a=t2.b;
52 SELECT * FROM t1 NATURAL JOIN t2;
54 } {a 1 b 2 c 3 d 4 a 2 b 3 c 4 d 5}
57 SELECT * FROM t2 NATURAL JOIN t1;
59 } {b 2 c 3 d 4 a 1 b 3 c 4 d 5 a 2}
62 SELECT * FROM t2 AS x NATURAL JOIN t1;
64 } {b 2 c 3 d 4 a 1 b 3 c 4 d 5 a 2}
67 SELECT * FROM t2 NATURAL JOIN t1 AS y;
69 } {b 2 c 3 d 4 a 1 b 3 c 4 d 5 a 2}
72 SELECT b FROM t1 NATURAL JOIN t2;
79 SELECT t2.* FROM t2 NATURAL JOIN t1
81 } {b 2 c 3 d 4 b 3 c 4 d 5}
84 SELECT xyzzy.* FROM t2 AS xyzzy NATURAL JOIN t1
86 } {b 2 c 3 d 4 b 3 c 4 d 5}
89 SELECT t1.* FROM t2 NATURAL JOIN t1
91 } {a 1 b 2 c 3 a 2 b 3 c 4}
94 SELECT xyzzy.* FROM t2 NATURAL JOIN t1 AS xyzzy
96 } {a 1 b 2 c 3 a 2 b 3 c 4}
99 SELECT aaa.*, bbb.* FROM t2 AS aaa NATURAL JOIN t1 AS bbb
101 } {b 2 c 3 d 4 a 1 b 2 c 3 b 3 c 4 d 5 a 2 b 3 c 4}
102 do_test join-1.3.10 {
104 SELECT t1.*, t2.* FROM t2 NATURAL JOIN t1
106 } {a 1 b 2 c 3 b 2 c 3 d 4 a 2 b 3 c 4 b 3 c 4 d 5}
111 SELECT * FROM t1 INNER JOIN t2 USING(b,c);
113 } {a 1 b 2 c 3 d 4 a 2 b 3 c 4 d 5}
116 SELECT * FROM t1 AS x INNER JOIN t2 USING(b,c);
118 } {a 1 b 2 c 3 d 4 a 2 b 3 c 4 d 5}
121 SELECT * FROM t1 INNER JOIN t2 AS y USING(b,c);
123 } {a 1 b 2 c 3 d 4 a 2 b 3 c 4 d 5}
126 SELECT * FROM t1 AS x INNER JOIN t2 AS y USING(b,c);
128 } {a 1 b 2 c 3 d 4 a 2 b 3 c 4 d 5}
131 SELECT b FROM t1 JOIN t2 USING(b);
138 SELECT t1.* FROM t1 JOIN t2 USING(b);
140 } {a 1 b 2 c 3 a 2 b 3 c 4}
143 SELECT t2.* FROM t1 JOIN t2 USING(b);
145 } {b 2 c 3 d 4 b 3 c 4 d 5}
149 SELECT * FROM t1 INNER JOIN t2 USING(b);
151 } {a 1 b 2 c 3 c 3 d 4 a 2 b 3 c 4 c 4 d 5}
154 SELECT * FROM t1 INNER JOIN t2 USING(c);
156 } {a 1 b 2 c 3 b 2 d 4 a 2 b 3 c 4 b 3 d 5}
159 SELECT * FROM t1 INNER JOIN t2 USING(c,b);
161 } {a 1 b 2 c 3 d 4 a 2 b 3 c 4 d 5}
165 SELECT * FROM t1 NATURAL CROSS JOIN t2;
170 SELECT * FROM t1 CROSS JOIN t2 USING(b,c);
175 SELECT * FROM t1 NATURAL INNER JOIN t2;
180 SELECT * FROM t1 INNER JOIN t2 USING(b,c);
185 SELECT * FROM t1 natural inner join t2;
192 SELECT * FROM t1 NATURAL JOIN
193 (SELECT b as 'c', c as 'd', d as 'e' FROM t2) as t3
195 } {a 1 b 2 c 3 d 4 e 5}
198 SELECT * FROM (SELECT b as 'c', c as 'd', d as 'e' FROM t2) as 'tx'
201 } {c 3 d 4 e 5 a 1 b 2}
206 CREATE TABLE t3(c,d,e);
207 INSERT INTO t3 VALUES(2,3,4);
208 INSERT INTO t3 VALUES(3,4,5);
209 INSERT INTO t3 VALUES(4,5,6);
212 } {2 3 4 3 4 5 4 5 6}
215 SELECT * FROM t1 natural join t2 natural join t3;
217 } {1 2 3 4 5 2 3 4 5 6}
220 SELECT * FROM t1 natural join t2 natural join t3;
222 } {a 1 b 2 c 3 d 4 e 5 a 2 b 3 c 4 d 5 e 6}
225 CREATE TABLE t4(d,e,f);
226 INSERT INTO t4 VALUES(2,3,4);
227 INSERT INTO t4 VALUES(3,4,5);
228 INSERT INTO t4 VALUES(4,5,6);
231 } {2 3 4 3 4 5 4 5 6}
232 do_test join-1.19.1 {
234 SELECT * FROM t1 natural join t2 natural join t4;
237 do_test join-1.19.2 {
239 SELECT * FROM t1 natural join t2 natural join t4;
241 } {a 1 b 2 c 3 d 4 e 5 f 6}
244 SELECT * FROM t1 natural join t2 natural join t3 WHERE t1.a=1
250 SELECT * FROM t1 NATURAL LEFT JOIN t2;
252 } {1 2 3 4 2 3 4 5 3 4 5 {}}
257 SELECT * FROM t1 NATURAL LEFT JOIN t2;
259 } {a 1 b 2 c 3 d 4 a 2 b 3 c 4 d 5 a 3 b 4 c 5 d {}}
262 SELECT t1.* FROM t1 NATURAL LEFT JOIN t2;
264 } {a 1 b 2 c 3 a 2 b 3 c 4 a 3 b 4 c 5}
267 SELECT t2.* FROM t1 NATURAL LEFT JOIN t2;
269 } {b 2 c 3 d 4 b 3 c 4 d 5 b {} c {} d {}}
273 SELECT * FROM t2 NATURAL LEFT OUTER JOIN t1;
275 } {1 2 3 {} 2 3 4 1 3 4 5 2}
278 SELECT * FROM t1 NATURAL RIGHT OUTER JOIN t2;
280 } {1 {RIGHT and FULL OUTER JOINs are not currently supported}}
283 SELECT * FROM t1 LEFT JOIN t2 ON t1.a=t2.d
285 } {1 2 3 {} {} {} 2 3 4 {} {} {} 3 4 5 1 2 3}
288 SELECT * FROM t1 LEFT JOIN t2 ON t1.a=t2.d WHERE t1.a>1
290 } {2 3 4 {} {} {} 3 4 5 1 2 3}
293 SELECT * FROM t1 LEFT JOIN t2 ON t1.a=t2.d WHERE t2.b IS NULL OR t2.b>1
295 } {1 2 3 {} {} {} 2 3 4 {} {} {}}
299 SELECT * FROM t1 NATURAL JOIN t2 ON t1.a=t2.b;
301 } {1 {a NATURAL join may not have an ON or USING clause}}
304 SELECT * FROM t1 NATURAL JOIN t2 USING(b);
306 } {1 {a NATURAL join may not have an ON or USING clause}}
309 SELECT * FROM t1 JOIN t2 ON t1.a=t2.b USING(b);
311 } {1 {cannot have both ON and USING clauses in the same join}}
314 SELECT * FROM t1 JOIN t2 USING(a);
316 } {1 {cannot join using column a - column not present in both tables}}
319 SELECT * FROM t1 JOIN t2 USING(d);
321 } {1 {cannot join using column d - column not present in both tables}}
323 catchsql { SELECT * FROM t1 USING(a) }
324 } {1 {a JOIN clause is required before USING}}
327 SELECT * FROM t1 JOIN t2 ON t3.a=t2.b;
329 } {1 {no such column: t3.a}}
332 SELECT * FROM t1 INNER OUTER JOIN t2;
334 } {1 {unknown or unsupported join type: INNER OUTER}}
337 SELECT * FROM t1 INNER OUTER CROSS JOIN t2;
339 } {1 {unknown or unsupported join type: INNER OUTER CROSS}}
342 SELECT * FROM t1 OUTER NATURAL INNER JOIN t2;
344 } {1 {unknown or unsupported join type: OUTER NATURAL INNER}}
347 SELECT * FROM t1 LEFT BOGUS JOIN t2;
349 } {1 {unknown or unsupported join type: LEFT BOGUS}}
352 SELECT * FROM t1 INNER BOGUS CROSS JOIN t2;
354 } {1 {unknown or unsupported join type: INNER BOGUS CROSS}}
357 SELECT * FROM t1 NATURAL AWK SED JOIN t2;
359 } {1 {unknown or unsupported join type: NATURAL AWK SED}}
364 CREATE TABLE t5(a INTEGER PRIMARY KEY);
365 CREATE TABLE t6(a INTEGER);
366 INSERT INTO t6 VALUES(NULL);
367 INSERT INTO t6 VALUES(NULL);
368 INSERT INTO t6 SELECT * FROM t6;
369 INSERT INTO t6 SELECT * FROM t6;
370 INSERT INTO t6 SELECT * FROM t6;
371 INSERT INTO t6 SELECT * FROM t6;
372 INSERT INTO t6 SELECT * FROM t6;
373 INSERT INTO t6 SELECT * FROM t6;
377 SELECT * FROM t6 NATURAL JOIN t5;
382 SELECT * FROM t6, t5 WHERE t6.a<t5.a;
387 SELECT * FROM t6, t5 WHERE t6.a>t5.a;
392 UPDATE t6 SET a='xyz';
393 SELECT * FROM t6 NATURAL JOIN t5;
398 SELECT * FROM t6, t5 WHERE t6.a<t5.a;
403 SELECT * FROM t6, t5 WHERE t6.a>t5.a;
409 SELECT * FROM t6 NATURAL JOIN t5;
414 SELECT * FROM t6, t5 WHERE t6.a<t5.a;
419 SELECT * FROM t6, t5 WHERE t6.a>t5.a;
426 create table centros (id integer primary key, centro);
427 INSERT INTO centros VALUES(1,'xxx');
428 create table usuarios (id integer primary key, nombre, apellidos,
430 INSERT INTO usuarios VALUES(1,'a','aa',1);
431 INSERT INTO usuarios VALUES(2,'b','bb',1);
432 INSERT INTO usuarios VALUES(3,'c','cc',NULL);
433 create index idcentro on usuarios (idcentro);
435 select usuarios.id, usuarios.nombre, centros.centro from
436 usuarios left outer join centros on usuarios.idcentro = centros.id;
438 } {1 a xxx 2 b xxx 3 c {}}
440 # A test for ticket #247.
444 CREATE TABLE t7 (x, y);
445 INSERT INTO t7 VALUES ("pa1", 1);
446 INSERT INTO t7 VALUES ("pa2", NULL);
447 INSERT INTO t7 VALUES ("pa3", NULL);
448 INSERT INTO t7 VALUES ("pa4", 2);
449 INSERT INTO t7 VALUES ("pa30", 131);
450 INSERT INTO t7 VALUES ("pa31", 130);
451 INSERT INTO t7 VALUES ("pa28", NULL);
453 CREATE TABLE t8 (a integer primary key, b);
454 INSERT INTO t8 VALUES (1, "pa1");
455 INSERT INTO t8 VALUES (2, "pa4");
456 INSERT INTO t8 VALUES (3, NULL);
457 INSERT INTO t8 VALUES (4, NULL);
458 INSERT INTO t8 VALUES (130, "pa31");
459 INSERT INTO t8 VALUES (131, "pa30");
461 SELECT coalesce(t8.a,999) from t7 LEFT JOIN t8 on y=a;
463 } {1 999 999 2 131 130 999}
465 # Make sure a left join where the right table is really a view that
466 # is itself a join works right. Ticket #306.
472 CREATE TABLE t9(a INTEGER PRIMARY KEY, b);
473 INSERT INTO t9 VALUES(1,11);
474 INSERT INTO t9 VALUES(2,22);
475 CREATE TABLE t10(x INTEGER PRIMARY KEY, y);
476 INSERT INTO t10 VALUES(1,2);
477 INSERT INTO t10 VALUES(3,3);
478 CREATE TABLE t11(p INTEGER PRIMARY KEY, q);
479 INSERT INTO t11 VALUES(2,111);
480 INSERT INTO t11 VALUES(3,333);
481 CREATE VIEW v10_11 AS SELECT x, q FROM t10, t11 WHERE t10.y=t11.p;
483 SELECT * FROM t9 LEFT JOIN v10_11 ON( a=x );
485 } {1 11 1 111 2 22 {} {}}
489 SELECT * FROM t9 LEFT JOIN (SELECT x, q FROM t10, t11 WHERE t10.y=t11.p)
492 } {1 11 1 111 2 22 {} {}}
496 SELECT * FROM v10_11 LEFT JOIN t9 ON( a=x );
498 } {1 111 1 11 3 333 {} {}}
500 # Constant expressions in a subquery that is the right element of a
501 # LEFT JOIN evaluate to NULL for rows where the LEFT JOIN does not
502 # match. Ticket #3300
505 SELECT * FROM t9 LEFT JOIN (SELECT 44, p, q FROM t11) AS sub1 ON p=a
507 } {1 11 {} {} {} 2 22 44 2 111}
511 # Ticket #350 describes a scenario where LEFT OUTER JOIN does not
512 # function correctly if the right table in the join is really
515 # To test the problem, we generate the same LEFT OUTER JOIN in two
516 # separate selects but with on using a subquery and the other calling
517 # the table directly. Then connect the two SELECTs using an EXCEPT.
518 # Both queries should generate the same results so the answer should
525 CREATE TABLE t12(a,b);
526 INSERT INTO t12 VALUES(1,11);
527 INSERT INTO t12 VALUES(2,22);
528 CREATE TABLE t13(b,c);
529 INSERT INTO t13 VALUES(22,222);
537 SELECT * FROM t12 NATURAL LEFT JOIN t13
539 SELECT * FROM t12 NATURAL LEFT JOIN (SELECT * FROM t13 WHERE b>0);
546 CREATE VIEW v13 AS SELECT * FROM t13 WHERE b>0;
547 SELECT * FROM t12 NATURAL LEFT JOIN t13
549 SELECT * FROM t12 NATURAL LEFT JOIN v13;
553 } ;# ifcapable compound
556 # Ticket #1697: Left Join WHERE clause terms that contain an
557 # aggregate subquery.
561 CREATE TABLE t21(a,b,c);
562 CREATE TABLE t22(p,q);
563 CREATE INDEX i22 ON t22(q);
564 SELECT a FROM t21 LEFT JOIN t22 ON b=p WHERE q=
565 (SELECT max(m.q) FROM t22 m JOIN t21 n ON n.b=m.p WHERE n.c=1);
569 # Test a LEFT JOIN when the right-hand side of hte join is an empty
570 # sub-query. Seems fine.
574 CREATE TABLE t23(a, b, c);
575 CREATE TABLE t24(a, b, c);
576 INSERT INTO t23 VALUES(1, 2, 3);
579 SELECT * FROM t23 LEFT JOIN t24;
584 SELECT * FROM t23 LEFT JOIN (SELECT * FROM t24);
588 } ;# ifcapable subquery
590 #-------------------------------------------------------------------------
591 # The following tests are to ensure that bug b73fb0bd64 is fixed.
596 CREATE TABLE t1(a INTEGER PRIMARY KEY, b TEXT);
597 CREATE TABLE t2(a INTEGER PRIMARY KEY, b TEXT);
598 INSERT INTO t1 VALUES(1,'abc');
599 INSERT INTO t1 VALUES(2,'def');
600 INSERT INTO t2 VALUES(1,'abc');
601 INSERT INTO t2 VALUES(2,'def');
602 SELECT * FROM t1 NATURAL JOIN t2;
607 execsql { SELECT a FROM t1 JOIN t1 USING (a)}
610 execsql { SELECT a FROM t1 JOIN t1 AS t2 USING (a)}
613 execsql { SELECT * FROM t1 NATURAL JOIN t1 AS t2}
616 execsql { SELECT * FROM t1 NATURAL JOIN t1 }
622 CREATE TABLE t1(a COLLATE nocase, b);
623 CREATE TABLE t2(a, b);
624 INSERT INTO t1 VALUES('ONE', 1);
625 INSERT INTO t1 VALUES('two', 2);
626 INSERT INTO t2 VALUES('one', 1);
627 INSERT INTO t2 VALUES('two', 2);
631 execsql { SELECT * FROM t1 NATURAL JOIN t2 }
634 execsql { SELECT * FROM t2 NATURAL JOIN t1 }
640 CREATE TABLE t1(a, b TEXT);
641 CREATE TABLE t2(b INTEGER, a);
642 INSERT INTO t1 VALUES('one', '1.0');
643 INSERT INTO t1 VALUES('two', '2');
644 INSERT INTO t2 VALUES(1, 'one');
645 INSERT INTO t2 VALUES(2, 'two');
649 execsql { SELECT * FROM t1 NATURAL JOIN t2 }
652 execsql { SELECT * FROM t2 NATURAL JOIN t1 }
655 #-------------------------------------------------------------------------
656 # Test that at most 64 tables are allowed in a join.
658 do_execsql_test join-12.1 {
660 INSERT INTO t14 VALUES('abcdefghij');
663 proc jointest {tn nTbl res} {
664 set sql "SELECT 1 FROM [string repeat t14, [expr $nTbl-1]] t14;"
665 uplevel [list do_catchsql_test $tn $sql $res]
668 jointest join-12.2 30 {0 1}
669 jointest join-12.3 63 {0 1}
670 jointest join-12.4 64 {0 1}
671 jointest join-12.5 65 {1 {at most 64 tables in a join}}
672 jointest join-12.6 66 {1 {at most 64 tables in a join}}
673 jointest join-12.7 127 {1 {at most 64 tables in a join}}
674 jointest join-12.8 128 {1 {at most 64 tables in a join}}
675 jointest join-12.9 1000 {1 {at most 64 tables in a join}}
677 # If SQLite is built with SQLITE_MEMDEBUG, then the huge number of realloc()
678 # calls made by the following test cases are too time consuming to run.
679 # Without SQLITE_MEMDEBUG, realloc() is fast enough that these are not
681 ifcapable pragma&&compileoption_diags {
682 if {[lsearch [db eval {PRAGMA compile_options}] MEMDEBUG]<0} {
683 jointest join-12.10 65534 {1 {at most 64 tables in a join}}
684 jointest join-12.11 65535 {1 {too many references to "t14": max 65535}}
685 jointest join-12.12 65536 {1 {too many references to "t14": max 65535}}
686 jointest join-12.13 65537 {1 {too many references to "t14": max 65535}}