xref: /sqlite-3.40.0/test/join.test (revision de7a820f)
1# 2002-05-24
2#
3# The author disclaims copyright to this source code.  In place of
4# a legal notice, here is a blessing:
5#
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.
9#
10#***********************************************************************
11# This file implements regression tests for SQLite library.
12#
13# This file implements tests for joins, including outer joins.
14#
15
16set testdir [file dirname $argv0]
17source $testdir/tester.tcl
18
19do_test join-1.1 {
20  execsql {
21    CREATE TABLE t1(a,b,c);
22    INSERT INTO t1 VALUES(1,2,3);
23    INSERT INTO t1 VALUES(2,3,4);
24    INSERT INTO t1 VALUES(3,4,5);
25    SELECT * FROM t1;
26  }
27} {1 2 3 2 3 4 3 4 5}
28do_test join-1.2 {
29  execsql {
30    CREATE TABLE t2(b,c,d);
31    INSERT INTO t2 VALUES(1,2,3);
32    INSERT INTO t2 VALUES(2,3,4);
33    INSERT INTO t2 VALUES(3,4,5);
34    SELECT * FROM t2;
35  }
36} {1 2 3 2 3 4 3 4 5}
37
38# A FROM clause of the form:  "<table>, <table> ON <expr>" is not
39# allowed by the SQLite syntax diagram, nor by any other SQL database
40# engine that we are aware of.  Nevertheless, historic versions of
41# SQLite have allowed it.  We need to continue to support it moving
42# forward to prevent breakage of legacy applications.  Though, we will
43# not advertise it as being supported.
44#
45do_execsql_test join-1.2.1 {
46  SELECT t1.rowid, t2.rowid, '|' FROM t1, t2 ON t1.a=t2.b;
47} {1 1 | 2 2 | 3 3 |}
48
49do_test join-1.3 {
50  execsql2 {
51    SELECT * FROM t1 NATURAL JOIN t2;
52  }
53} {a 1 b 2 c 3 d 4 a 2 b 3 c 4 d 5}
54do_test join-1.3.1 {
55  execsql2 {
56    SELECT * FROM t2 NATURAL JOIN t1;
57  }
58} {b 2 c 3 d 4 a 1 b 3 c 4 d 5 a 2}
59do_test join-1.3.2 {
60  execsql2 {
61    SELECT * FROM t2 AS x NATURAL JOIN t1;
62  }
63} {b 2 c 3 d 4 a 1 b 3 c 4 d 5 a 2}
64do_test join-1.3.3 {
65  execsql2 {
66    SELECT * FROM t2 NATURAL JOIN t1 AS y;
67  }
68} {b 2 c 3 d 4 a 1 b 3 c 4 d 5 a 2}
69do_test join-1.3.4 {
70  execsql {
71    SELECT b FROM t1 NATURAL JOIN t2;
72  }
73} {2 3}
74
75# ticket #3522
76do_test join-1.3.5 {
77  execsql2 {
78    SELECT t2.* FROM t2 NATURAL JOIN t1
79  }
80} {b 2 c 3 d 4 b 3 c 4 d 5}
81do_test join-1.3.6 {
82  execsql2 {
83    SELECT xyzzy.* FROM t2 AS xyzzy NATURAL JOIN t1
84  }
85} {b 2 c 3 d 4 b 3 c 4 d 5}
86do_test join-1.3.7 {
87  execsql2 {
88    SELECT t1.* FROM t2 NATURAL JOIN t1
89  }
90} {a 1 b 2 c 3 a 2 b 3 c 4}
91do_test join-1.3.8 {
92  execsql2 {
93    SELECT xyzzy.* FROM t2 NATURAL JOIN t1 AS xyzzy
94  }
95} {a 1 b 2 c 3 a 2 b 3 c 4}
96do_test join-1.3.9 {
97  execsql2 {
98    SELECT aaa.*, bbb.* FROM t2 AS aaa NATURAL JOIN t1 AS bbb
99  }
100} {b 2 c 3 d 4 a 1 b 2 c 3 b 3 c 4 d 5 a 2 b 3 c 4}
101do_test join-1.3.10 {
102  execsql2 {
103    SELECT t1.*, t2.* FROM t2 NATURAL JOIN t1
104  }
105} {a 1 b 2 c 3 b 2 c 3 d 4 a 2 b 3 c 4 b 3 c 4 d 5}
106
107
108do_test join-1.4.1 {
109  execsql2 {
110    SELECT * FROM t1 INNER JOIN t2 USING(b,c);
111  }
112} {a 1 b 2 c 3 d 4 a 2 b 3 c 4 d 5}
113do_test join-1.4.2 {
114  execsql2 {
115    SELECT * FROM t1 AS x INNER JOIN t2 USING(b,c);
116  }
117} {a 1 b 2 c 3 d 4 a 2 b 3 c 4 d 5}
118do_test join-1.4.3 {
119  execsql2 {
120    SELECT * FROM t1 INNER JOIN t2 AS y USING(b,c);
121  }
122} {a 1 b 2 c 3 d 4 a 2 b 3 c 4 d 5}
123do_test join-1.4.4 {
124  execsql2 {
125    SELECT * FROM t1 AS x INNER JOIN t2 AS y USING(b,c);
126  }
127} {a 1 b 2 c 3 d 4 a 2 b 3 c 4 d 5}
128do_test join-1.4.5 {
129  execsql {
130    SELECT b FROM t1 JOIN t2 USING(b);
131  }
132} {2 3}
133
134# Ticket #3522
135do_test join-1.4.6 {
136  execsql2 {
137    SELECT t1.* FROM t1 JOIN t2 USING(b);
138  }
139} {a 1 b 2 c 3 a 2 b 3 c 4}
140do_test join-1.4.7 {
141  execsql2 {
142    SELECT t2.* FROM t1 JOIN t2 USING(b);
143  }
144} {b 2 c 3 d 4 b 3 c 4 d 5}
145
146do_test join-1.5 {
147  execsql2 {
148    SELECT * FROM t1 INNER JOIN t2 USING(b);
149  }
150} {a 1 b 2 c 3 c 3 d 4 a 2 b 3 c 4 c 4 d 5}
151do_test join-1.6 {
152  execsql2 {
153    SELECT * FROM t1 INNER JOIN t2 USING(c);
154  }
155} {a 1 b 2 c 3 b 2 d 4 a 2 b 3 c 4 b 3 d 5}
156do_test join-1.7 {
157  execsql2 {
158    SELECT * FROM t1 INNER JOIN t2 USING(c,b);
159  }
160} {a 1 b 2 c 3 d 4 a 2 b 3 c 4 d 5}
161
162do_test join-1.8 {
163  execsql {
164    SELECT * FROM t1 NATURAL CROSS JOIN t2;
165  }
166} {1 2 3 4 2 3 4 5}
167do_test join-1.9 {
168  execsql {
169    SELECT * FROM t1 CROSS JOIN t2 USING(b,c);
170  }
171} {1 2 3 4 2 3 4 5}
172do_test join-1.10 {
173  execsql {
174    SELECT * FROM t1 NATURAL INNER JOIN t2;
175  }
176} {1 2 3 4 2 3 4 5}
177do_test join-1.11 {
178  execsql {
179    SELECT * FROM t1 INNER JOIN t2 USING(b,c);
180  }
181} {1 2 3 4 2 3 4 5}
182do_test join-1.12 {
183  execsql {
184    SELECT * FROM t1 natural inner join t2;
185  }
186} {1 2 3 4 2 3 4 5}
187
188ifcapable subquery {
189  do_test join-1.13 {
190    execsql2 {
191      SELECT * FROM t1 NATURAL JOIN
192        (SELECT b as 'c', c as 'd', d as 'e' FROM t2) as t3
193    }
194  } {a 1 b 2 c 3 d 4 e 5}
195  do_test join-1.14 {
196    execsql2 {
197      SELECT * FROM (SELECT b as 'c', c as 'd', d as 'e' FROM t2) as 'tx'
198          NATURAL JOIN t1
199    }
200  } {c 3 d 4 e 5 a 1 b 2}
201}
202
203do_test join-1.15 {
204  execsql {
205    CREATE TABLE t3(c,d,e);
206    INSERT INTO t3 VALUES(2,3,4);
207    INSERT INTO t3 VALUES(3,4,5);
208    INSERT INTO t3 VALUES(4,5,6);
209    SELECT * FROM t3;
210  }
211} {2 3 4 3 4 5 4 5 6}
212do_test join-1.16 {
213  execsql {
214    SELECT * FROM t1 natural join t2 natural join t3;
215  }
216} {1 2 3 4 5 2 3 4 5 6}
217do_test join-1.17 {
218  execsql2 {
219    SELECT * FROM t1 natural join t2 natural join t3;
220  }
221} {a 1 b 2 c 3 d 4 e 5 a 2 b 3 c 4 d 5 e 6}
222do_test join-1.18 {
223  execsql {
224    CREATE TABLE t4(d,e,f);
225    INSERT INTO t4 VALUES(2,3,4);
226    INSERT INTO t4 VALUES(3,4,5);
227    INSERT INTO t4 VALUES(4,5,6);
228    SELECT * FROM t4;
229  }
230} {2 3 4 3 4 5 4 5 6}
231do_test join-1.19.1 {
232  execsql {
233    SELECT * FROM t1 natural join t2 natural join t4;
234  }
235} {1 2 3 4 5 6}
236do_test join-1.19.2 {
237  execsql2 {
238    SELECT * FROM t1 natural join t2 natural join t4;
239  }
240} {a 1 b 2 c 3 d 4 e 5 f 6}
241do_test join-1.20 {
242  execsql {
243    SELECT * FROM t1 natural join t2 natural join t3 WHERE t1.a=1
244  }
245} {1 2 3 4 5}
246
247do_test join-2.1 {
248  execsql {
249    SELECT * FROM t1 NATURAL LEFT JOIN t2;
250  }
251} {1 2 3 4 2 3 4 5 3 4 5 {}}
252
253# ticket #3522
254do_test join-2.1.1 {
255  execsql2 {
256    SELECT * FROM t1 NATURAL LEFT JOIN t2;
257  }
258} {a 1 b 2 c 3 d 4 a 2 b 3 c 4 d 5 a 3 b 4 c 5 d {}}
259do_test join-2.1.2 {
260  execsql2 {
261    SELECT t1.* FROM t1 NATURAL LEFT JOIN t2;
262  }
263} {a 1 b 2 c 3 a 2 b 3 c 4 a 3 b 4 c 5}
264do_test join-2.1.3 {
265  execsql2 {
266    SELECT t2.* FROM t1 NATURAL LEFT JOIN t2;
267  }
268} {b 2 c 3 d 4 b 3 c 4 d 5 b {} c {} d {}}
269
270do_test join-2.2 {
271  execsql {
272    SELECT * FROM t2 NATURAL LEFT OUTER JOIN t1;
273  }
274} {1 2 3 {} 2 3 4 1 3 4 5 2}
275
276#do_test join-2.3 {
277#  catchsql {
278#    SELECT * FROM t1 NATURAL RIGHT OUTER JOIN t2;
279#  }
280#} {1 {RIGHT and FULL OUTER JOINs are not currently supported}}
281
282do_test join-2.4 {
283  execsql {
284    SELECT * FROM t1 LEFT JOIN t2 ON t1.a=t2.d
285  }
286} {1 2 3 {} {} {} 2 3 4 {} {} {} 3 4 5 1 2 3}
287do_test join-2.5 {
288  execsql {
289    SELECT * FROM t1 LEFT JOIN t2 ON t1.a=t2.d WHERE t1.a>1
290  }
291} {2 3 4 {} {} {} 3 4 5 1 2 3}
292do_test join-2.6 {
293  execsql {
294    SELECT * FROM t1 LEFT JOIN t2 ON t1.a=t2.d WHERE t2.b IS NULL OR t2.b>1
295  }
296} {1 2 3 {} {} {} 2 3 4 {} {} {}}
297
298do_test join-3.1 {
299  catchsql {
300    SELECT * FROM t1 NATURAL JOIN t2 ON t1.a=t2.b;
301  }
302} {1 {a NATURAL join may not have an ON or USING clause}}
303do_test join-3.2 {
304  catchsql {
305    SELECT * FROM t1 NATURAL JOIN t2 USING(b);
306  }
307} {1 {a NATURAL join may not have an ON or USING clause}}
308do_test join-3.3 {
309  catchsql {
310    SELECT * FROM t1 JOIN t2 ON t1.a=t2.b USING(b);
311  }
312} {1 {near "USING": syntax error}}
313do_test join-3.4.1 {
314  catchsql {
315    SELECT * FROM t1 JOIN t2 USING(a);
316  }
317} {1 {cannot join using column a - column not present in both tables}}
318do_test join-3.4.2 {
319  catchsql {
320    SELECT * FROM t1 JOIN t2 USING(d);
321  }
322} {1 {cannot join using column d - column not present in both tables}}
323do_test join-3.5 {
324  catchsql { SELECT * FROM t1 USING(a) }
325} {1 {a JOIN clause is required before USING}}
326do_test join-3.6 {
327  catchsql {
328    SELECT * FROM t1 JOIN t2 ON t3.a=t2.b;
329  }
330} {1 {no such column: t3.a}}
331do_test join-3.7 {
332  catchsql {
333    SELECT * FROM t1 INNER OUTER JOIN t2;
334  }
335} {1 {unknown join type: INNER OUTER}}
336do_test join-3.8 {
337  catchsql {
338    SELECT * FROM t1 INNER OUTER CROSS JOIN t2;
339  }
340} {1 {unknown join type: INNER OUTER CROSS}}
341do_test join-3.9 {
342  catchsql {
343    SELECT * FROM t1 OUTER NATURAL INNER JOIN t2;
344  }
345} {1 {unknown join type: OUTER NATURAL INNER}}
346do_test join-3.10 {
347  catchsql {
348    SELECT * FROM t1 LEFT BOGUS JOIN t2;
349  }
350} {1 {unknown join type: LEFT BOGUS}}
351do_test join-3.11 {
352  catchsql {
353    SELECT * FROM t1 INNER BOGUS CROSS JOIN t2;
354  }
355} {1 {unknown join type: INNER BOGUS CROSS}}
356do_test join-3.12 {
357  catchsql {
358    SELECT * FROM t1 NATURAL AWK SED JOIN t2;
359  }
360} {1 {unknown join type: NATURAL AWK SED}}
361
362do_test join-4.1 {
363  execsql {
364    BEGIN;
365    CREATE TABLE t5(a INTEGER PRIMARY KEY);
366    CREATE TABLE t6(a INTEGER);
367    INSERT INTO t6 VALUES(NULL);
368    INSERT INTO t6 VALUES(NULL);
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;
374    INSERT INTO t6 SELECT * FROM t6;
375    COMMIT;
376  }
377  execsql {
378    SELECT * FROM t6 NATURAL JOIN t5;
379  }
380} {}
381do_test join-4.2 {
382  execsql {
383    SELECT * FROM t6, t5 WHERE t6.a<t5.a;
384  }
385} {}
386do_test join-4.3 {
387  execsql {
388    SELECT * FROM t6, t5 WHERE t6.a>t5.a;
389  }
390} {}
391do_test join-4.4 {
392  execsql {
393    UPDATE t6 SET a='xyz';
394    SELECT * FROM t6 NATURAL JOIN t5;
395  }
396} {}
397do_test join-4.6 {
398  execsql {
399    SELECT * FROM t6, t5 WHERE t6.a<t5.a;
400  }
401} {}
402do_test join-4.7 {
403  execsql {
404    SELECT * FROM t6, t5 WHERE t6.a>t5.a;
405  }
406} {}
407do_test join-4.8 {
408  execsql {
409    UPDATE t6 SET a=1;
410    SELECT * FROM t6 NATURAL JOIN t5;
411  }
412} {}
413do_test join-4.9 {
414  execsql {
415    SELECT * FROM t6, t5 WHERE t6.a<t5.a;
416  }
417} {}
418do_test join-4.10 {
419  execsql {
420    SELECT * FROM t6, t5 WHERE t6.a>t5.a;
421  }
422} {}
423
424do_test join-5.1 {
425  execsql {
426    BEGIN;
427    create table centros (id integer primary key, centro);
428    INSERT INTO centros VALUES(1,'xxx');
429    create table usuarios (id integer primary key, nombre, apellidos,
430    idcentro integer);
431    INSERT INTO usuarios VALUES(1,'a','aa',1);
432    INSERT INTO usuarios VALUES(2,'b','bb',1);
433    INSERT INTO usuarios VALUES(3,'c','cc',NULL);
434    create index idcentro on usuarios (idcentro);
435    END;
436    select usuarios.id, usuarios.nombre, centros.centro from
437    usuarios left outer join centros on usuarios.idcentro = centros.id;
438  }
439} {1 a xxx 2 b xxx 3 c {}}
440
441# A test for ticket #247.
442#
443do_test join-7.1 {
444  sqlite3_db_config db SQLITE_DBCONFIG_DQS_DML 1
445  execsql {
446    CREATE TABLE t7 (x, y);
447    INSERT INTO t7 VALUES ("pa1", 1);
448    INSERT INTO t7 VALUES ("pa2", NULL);
449    INSERT INTO t7 VALUES ("pa3", NULL);
450    INSERT INTO t7 VALUES ("pa4", 2);
451    INSERT INTO t7 VALUES ("pa30", 131);
452    INSERT INTO t7 VALUES ("pa31", 130);
453    INSERT INTO t7 VALUES ("pa28", NULL);
454
455    CREATE TABLE t8 (a integer primary key, b);
456    INSERT INTO t8 VALUES (1, "pa1");
457    INSERT INTO t8 VALUES (2, "pa4");
458    INSERT INTO t8 VALUES (3, NULL);
459    INSERT INTO t8 VALUES (4, NULL);
460    INSERT INTO t8 VALUES (130, "pa31");
461    INSERT INTO t8 VALUES (131, "pa30");
462
463    SELECT coalesce(t8.a,999) from t7 LEFT JOIN t8 on y=a;
464  }
465} {1 999 999 2 131 130 999}
466
467# Make sure a left join where the right table is really a view that
468# is itself a join works right.  Ticket #306.
469#
470ifcapable view {
471do_test join-8.1 {
472  execsql {
473    BEGIN;
474    CREATE TABLE t9(a INTEGER PRIMARY KEY, b);
475    INSERT INTO t9 VALUES(1,11);
476    INSERT INTO t9 VALUES(2,22);
477    CREATE TABLE t10(x INTEGER PRIMARY KEY, y);
478    INSERT INTO t10 VALUES(1,2);
479    INSERT INTO t10 VALUES(3,3);
480    CREATE TABLE t11(p INTEGER PRIMARY KEY, q);
481    INSERT INTO t11 VALUES(2,111);
482    INSERT INTO t11 VALUES(3,333);
483    CREATE VIEW v10_11 AS SELECT x, q FROM t10, t11 WHERE t10.y=t11.p;
484    COMMIT;
485    SELECT * FROM t9 LEFT JOIN v10_11 ON( a=x );
486  }
487} {1 11 1 111 2 22 {} {}}
488ifcapable subquery {
489  do_test join-8.2 {
490    execsql {
491      SELECT * FROM t9 LEFT JOIN (SELECT x, q FROM t10, t11 WHERE t10.y=t11.p)
492           ON( a=x);
493    }
494  } {1 11 1 111 2 22 {} {}}
495}
496do_test join-8.3 {
497  execsql {
498    SELECT * FROM v10_11 LEFT JOIN t9 ON( a=x );
499  }
500} {1 111 1 11 3 333 {} {}}
501ifcapable subquery {
502  # Constant expressions in a subquery that is the right element of a
503  # LEFT JOIN evaluate to NULL for rows where the LEFT JOIN does not
504  # match.  Ticket #3300
505  do_test join-8.4 {
506    execsql {
507      SELECT * FROM t9 LEFT JOIN (SELECT 44, p, q FROM t11) AS sub1 ON p=a
508    }
509  } {1 11 {} {} {} 2 22 44 2 111}
510}
511} ;# ifcapable view
512
513# Ticket #350 describes a scenario where LEFT OUTER JOIN does not
514# function correctly if the right table in the join is really
515# subquery.
516#
517# To test the problem, we generate the same LEFT OUTER JOIN in two
518# separate selects but with on using a subquery and the other calling
519# the table directly.  Then connect the two SELECTs using an EXCEPT.
520# Both queries should generate the same results so the answer should
521# be an empty set.
522#
523ifcapable compound {
524do_test join-9.1 {
525  execsql {
526    BEGIN;
527    CREATE TABLE t12(a,b);
528    INSERT INTO t12 VALUES(1,11);
529    INSERT INTO t12 VALUES(2,22);
530    CREATE TABLE t13(b,c);
531    INSERT INTO t13 VALUES(22,222);
532    COMMIT;
533  }
534} {}
535
536ifcapable subquery {
537  do_test join-9.1.1 {
538    execsql {
539      SELECT * FROM t12 NATURAL LEFT JOIN t13
540      EXCEPT
541      SELECT * FROM t12 NATURAL LEFT JOIN (SELECT * FROM t13 WHERE b>0);
542    }
543  } {}
544}
545ifcapable view {
546  do_test join-9.2 {
547    execsql {
548      CREATE VIEW v13 AS SELECT * FROM t13 WHERE b>0;
549      SELECT * FROM t12 NATURAL LEFT JOIN t13
550        EXCEPT
551        SELECT * FROM t12 NATURAL LEFT JOIN v13;
552    }
553  } {}
554} ;# ifcapable view
555} ;# ifcapable compound
556
557ifcapable subquery {
558  # Ticket #1697:  Left Join WHERE clause terms that contain an
559  # aggregate subquery.
560  #
561  do_test join-10.1 {
562    execsql {
563      CREATE TABLE t21(a,b,c);
564      CREATE TABLE t22(p,q);
565      CREATE INDEX i22 ON t22(q);
566      SELECT a FROM t21 LEFT JOIN t22 ON b=p WHERE q=
567         (SELECT max(m.q) FROM t22 m JOIN t21 n ON n.b=m.p WHERE n.c=1);
568    }
569  } {}
570
571  # Test a LEFT JOIN when the right-hand side of hte join is an empty
572  # sub-query. Seems fine.
573  #
574  do_test join-10.2 {
575    execsql {
576      CREATE TABLE t23(a, b, c);
577      CREATE TABLE t24(a, b, c);
578      INSERT INTO t23 VALUES(1, 2, 3);
579    }
580    execsql {
581      SELECT * FROM t23 LEFT JOIN t24;
582    }
583  } {1 2 3 {} {} {}}
584  do_test join-10.3 {
585    execsql {
586      SELECT * FROM t23 LEFT JOIN (SELECT * FROM t24);
587    }
588  } {1 2 3 {} {} {}}
589
590} ;# ifcapable subquery
591
592#-------------------------------------------------------------------------
593# The following tests are to ensure that bug b73fb0bd64 is fixed.
594#
595do_test join-11.1 {
596  drop_all_tables
597  execsql {
598    CREATE TABLE t1(a INTEGER PRIMARY KEY, b TEXT);
599    CREATE TABLE t2(a INTEGER PRIMARY KEY, b TEXT);
600    INSERT INTO t1 VALUES(1,'abc');
601    INSERT INTO t1 VALUES(2,'def');
602    INSERT INTO t2 VALUES(1,'abc');
603    INSERT INTO t2 VALUES(2,'def');
604    SELECT * FROM t1 NATURAL JOIN t2;
605  }
606} {1 abc 2 def}
607
608do_test join-11.2 {
609  execsql { SELECT a FROM t1 JOIN t1 USING (a)}
610} {1 2}
611do_test join-11.3 {
612  execsql { SELECT a FROM t1 JOIN t1 AS t2 USING (a)}
613} {1 2}
614do_test join-11.3 {
615  execsql { SELECT * FROM t1 NATURAL JOIN t1 AS t2}
616} {1 abc 2 def}
617do_test join-11.4 {
618  execsql { SELECT * FROM t1 NATURAL JOIN t1 }
619} {1 abc 2 def}
620
621do_test join-11.5 {
622  drop_all_tables
623  execsql {
624    CREATE TABLE t1(a COLLATE nocase, b);
625    CREATE TABLE t2(a, b);
626    INSERT INTO t1 VALUES('ONE', 1);
627    INSERT INTO t1 VALUES('two', 2);
628    INSERT INTO t2 VALUES('one', 1);
629    INSERT INTO t2 VALUES('two', 2);
630  }
631} {}
632do_test join-11.6 {
633  execsql { SELECT * FROM t1 NATURAL JOIN t2 }
634} {ONE 1 two 2}
635do_test join-11.7 {
636  execsql { SELECT * FROM t2 NATURAL JOIN t1 }
637} {two 2}
638
639do_test join-11.8 {
640  drop_all_tables
641  execsql {
642    CREATE TABLE t1(a, b TEXT);
643    CREATE TABLE t2(b INTEGER, a);
644    INSERT INTO t1 VALUES('one', '1.0');
645    INSERT INTO t1 VALUES('two', '2');
646    INSERT INTO t2 VALUES(1, 'one');
647    INSERT INTO t2 VALUES(2, 'two');
648  }
649} {}
650do_test join-11.9 {
651  execsql { SELECT * FROM t1 NATURAL JOIN t2 }
652} {one 1.0 two 2}
653do_test join-11.10 {
654  execsql { SELECT * FROM t2 NATURAL JOIN t1 }
655} {1 one 2 two}
656
657#-------------------------------------------------------------------------
658# Test that at most 64 tables are allowed in a join.
659#
660do_execsql_test join-12.1 {
661  CREATE TABLE t14(x);
662  INSERT INTO t14 VALUES('abcdefghij');
663}
664
665proc jointest {tn nTbl res} {
666  set sql "SELECT 1 FROM [string repeat t14, [expr $nTbl-1]] t14;"
667  uplevel [list do_catchsql_test $tn $sql $res]
668}
669
670jointest join-12.2 30 {0 1}
671jointest join-12.3 63 {0 1}
672jointest join-12.4 64 {0 1}
673jointest join-12.5 65 {1 {at most 64 tables in a join}}
674jointest join-12.6 66 {1 {at most 64 tables in a join}}
675jointest join-12.7 127 {1 {at most 64 tables in a join}}
676jointest join-12.8 128 {1 {at most 64 tables in a join}}
677
678# As of 2019-01-17, the number of elements in a SrcList is limited
679# to 200.  The following tests still run, but the answer is now
680# an SQLITE_NOMEM error.
681#
682# jointest join-12.9 1000 {1 {at most 64 tables in a join}}
683#
684#  If SQLite is built with SQLITE_MEMDEBUG, then the huge number of realloc()
685#  calls made by the following test cases are too time consuming to run.
686#  Without SQLITE_MEMDEBUG, realloc() is fast enough that these are not
687#  a problem.
688#
689# ifcapable pragma&&compileoption_diags {
690#    if {[lsearch [db eval {PRAGMA compile_options}] MEMDEBUG]<0} {
691#     jointest join-12.10 65534 {1 {at most 64 tables in a join}}
692#     jointest join-12.11 65535 {1 {too many references to "t14": max 65535}}
693#     jointest join-12.12 65536 {1 {too many references to "t14": max 65535}}
694#     jointest join-12.13 65537 {1 {too many references to "t14": max 65535}}
695#   }
696# }
697
698
699#-------------------------------------------------------------------------
700# Test a problem with reordering tables following a LEFT JOIN.
701#
702do_execsql_test join-13.0 {
703  CREATE TABLE aa(a);
704  CREATE TABLE bb(b);
705  CREATE TABLE cc(c);
706
707  INSERT INTO aa VALUES(45);
708  INSERT INTO cc VALUES(45);
709  INSERT INTO cc VALUES(45);
710}
711
712do_execsql_test join-13.1 {
713  SELECT * FROM aa LEFT JOIN bb, cc WHERE cc.c=aa.a;
714} {45 {} 45 45 {} 45}
715
716# In the following, the order of [cc] and [bb] must not be exchanged, even
717# though this would be helpful if the query used an inner join.
718do_execsql_test join-13.2 {
719  CREATE INDEX ccc ON cc(c);
720  SELECT * FROM aa LEFT JOIN bb, cc WHERE cc.c=aa.a;
721} {45 {} 45 45 {} 45}
722
723# Verify that that iTable attributes the TK_IF_NULL_ROW operators in the
724# expression tree are correctly updated by the query flattener.  This was
725# a bug discovered on 2017-05-22 by Mark Brand.
726#
727do_execsql_test join-14.1 {
728  SELECT *
729    FROM (SELECT 1 a) AS x
730         LEFT JOIN (SELECT 1, * FROM (SELECT * FROM (SELECT 1)));
731} {1 1 1}
732do_execsql_test join-14.2 {
733  SELECT *
734  FROM (SELECT 1 a) AS x
735    LEFT JOIN (SELECT 1, * FROM (SELECT * FROM (SELECT * FROM (SELECT 1)))) AS y
736    JOIN (SELECT * FROM (SELECT 9)) AS z;
737} {1 1 1 9}
738do_execsql_test join-14.3 {
739  SELECT *
740  FROM (SELECT 111)
741  LEFT JOIN (SELECT cc+222, * FROM (SELECT * FROM (SELECT 333 cc)));
742} {111 555 333}
743
744do_execsql_test join-14.4 {
745  DROP TABLE IF EXISTS t1;
746  CREATE TABLE t1(c PRIMARY KEY, a TEXT(10000), b TEXT(10000));
747  SELECT * FROM (SELECT 111) LEFT JOIN (SELECT c+222 FROM t1) GROUP BY 1;
748} {111 {}}
749do_execsql_test join-14.5 {
750  DROP TABLE IF EXISTS t1;
751  CREATE TABLE t1(c PRIMARY KEY) WITHOUT ROWID;
752  SELECT * FROM (SELECT 111) LEFT JOIN (SELECT c+222 FROM t1) GROUP BY 1;
753} {111 {}}
754
755# Verify the fix to ticket
756# https://www.sqlite.org/src/tktview/7fde638e94287d2c948cd9389
757#
758db close
759sqlite3 db :memory:
760do_execsql_test join-14.10 {
761  CREATE TABLE t1(a);
762  INSERT INTO t1 VALUES(1),(2),(3);
763  CREATE VIEW v2 AS SELECT a, 1 AS b FROM t1;
764  CREATE TABLE t3(x);
765  INSERT INTO t3 VALUES(2),(4);
766  SELECT *, '|' FROM t3 LEFT JOIN v2 ON a=x WHERE b=1;
767} {2 2 1 |}
768do_execsql_test join-14.11 {
769  SELECT *, '|' FROM t3 LEFT JOIN v2 ON a=x WHERE b+1=x;
770} {2 2 1 |}
771do_execsql_test join-14.12 {
772  SELECT *, '|' FROM t3 LEFT JOIN v2 ON a=x ORDER BY b;
773} {4 {} {} | 2 2 1 |}
774
775# Verify the fix for ticket
776# https://www.sqlite.org/src/info/892fc34f173e99d8
777#
778db close
779sqlite3 db :memory:
780do_execsql_test join-14.20 {
781  CREATE TABLE t1(id INTEGER PRIMARY KEY);
782  CREATE TABLE t2(id INTEGER PRIMARY KEY, c2 INTEGER);
783  CREATE TABLE t3(id INTEGER PRIMARY KEY, c3 INTEGER);
784  INSERT INTO t1(id) VALUES(456);
785  INSERT INTO t3(id) VALUES(1),(2);
786  SELECT t1.id, x2.id, x3.id
787  FROM t1
788  LEFT JOIN (SELECT * FROM t2) AS x2 ON t1.id=x2.c2
789  LEFT JOIN t3 AS x3 ON x2.id=x3.c3;
790} {456 {} {}}
791
792# 2018-03-24.
793# E.Pasma discovered that the LEFT JOIN strength reduction optimization
794# was misbehaving.  The problem turned out to be that the
795# sqlite3ExprImpliesNotNull() routine was saying that CASE expressions
796# like
797#
798#     CASE WHEN true THEN true ELSE x=0 END
799#
800# could never be true if x is NULL.  The following test cases verify
801# that this error has been resolved.
802#
803db close
804sqlite3 db :memory:
805do_execsql_test join-15.100 {
806  CREATE TABLE t1(a INT, b INT);
807  INSERT INTO t1 VALUES(1,2),(3,4);
808  CREATE TABLE t2(x INT, y INT);
809  SELECT *, 'x'
810    FROM t1 LEFT JOIN t2
811   WHERE CASE WHEN FALSE THEN a=x ELSE 1 END;
812} {1 2 {} {} x 3 4 {} {} x}
813do_execsql_test join-15.105 {
814  SELECT *, 'x'
815    FROM t1 LEFT JOIN t2
816   WHERE a IN (1,3,x,y);
817} {1 2 {} {} x 3 4 {} {} x}
818do_execsql_test join-15.106a {
819  SELECT *, 'x'
820    FROM t1 LEFT JOIN t2
821   WHERE NOT ( 'x'='y' AND t2.y=1 );
822} {1 2 {} {} x 3 4 {} {} x}
823do_execsql_test join-15.106b {
824  SELECT *, 'x'
825    FROM t1 LEFT JOIN t2
826   WHERE ~ ( 'x'='y' AND t2.y=1 );
827} {1 2 {} {} x 3 4 {} {} x}
828do_execsql_test join-15.107 {
829  SELECT *, 'x'
830    FROM t1 LEFT JOIN t2
831   WHERE t2.y IS NOT 'abc'
832} {1 2 {} {} x 3 4 {} {} x}
833do_execsql_test join-15.110 {
834  DROP TABLE t1;
835  DROP TABLE t2;
836  CREATE TABLE t1(a INTEGER PRIMARY KEY, b INTEGER);
837  INSERT INTO t1(a,b) VALUES(1,0),(11,1),(12,1),(13,1),(121,12);
838  CREATE INDEX t1b ON t1(b);
839  CREATE TABLE t2(x INTEGER PRIMARY KEY);
840  INSERT INTO t2(x) VALUES(0),(1);
841  SELECT  a1, a2, a3, a4, a5
842   FROM (SELECT a AS a1 FROM t1 WHERE b=0)
843        JOIN (SELECT x AS x1 FROM t2)
844        LEFT JOIN (SELECT a AS a2, b AS b2 FROM t1)
845          ON x1 IS TRUE AND b2=a1
846        JOIN (SELECT x AS x2 FROM t2)
847          ON x2<=CASE WHEN x1 THEN CASE WHEN a2 THEN 1 ELSE -1 END ELSE 0 END
848        LEFT JOIN (SELECT a AS a3, b AS b3 FROM t1)
849          ON x2 IS TRUE AND b3=a2
850        JOIN (SELECT x AS x3 FROM t2)
851          ON x3<=CASE WHEN x2 THEN CASE WHEN a3 THEN 1 ELSE -1 END ELSE 0 END
852        LEFT JOIN (SELECT a AS a4, b AS b4 FROM t1)
853          ON x3 IS TRUE AND b4=a3
854        JOIN (SELECT x AS x4 FROM t2)
855          ON x4<=CASE WHEN x3 THEN CASE WHEN a4 THEN 1 ELSE -1 END ELSE 0 END
856        LEFT JOIN (SELECT a AS a5, b AS b5 FROM t1)
857          ON x4 IS TRUE AND b5=a4
858   ORDER BY a1, a2, a3, a4, a5;
859} {1 {} {} {} {} 1 11 {} {} {} 1 12 {} {} {} 1 12 121 {} {} 1 13 {} {} {}}
860
861# 2019-02-05 Ticket https://www.sqlite.org/src/tktview/5948e09b8c415bc45da5c
862# Error in join due to the LEFT JOIN strength reduction optimization.
863#
864do_execsql_test join-16.100 {
865  DROP TABLE IF EXISTS t1;
866  DROP TABLE IF EXISTS t2;
867  CREATE TABLE t1(a INT);
868  INSERT INTO t1(a) VALUES(1);
869  CREATE TABLE t2(b INT);
870  SELECT a, b
871    FROM t1 LEFT JOIN t2 ON 0
872   WHERE (b IS NOT NULL)=0;
873} {1 {}}
874
875# 2019-08-17 ticket https://sqlite.org/src/tktview/6710d2f7a13a299728ab
876# Ensure that constants that derive from the right-hand table of a LEFT JOIN
877# are never factored out, since they are not really constant.
878#
879do_execsql_test join-17.100 {
880  DROP TABLE IF EXISTS t1;
881  CREATE TABLE t1(x);
882  INSERT INTO t1(x) VALUES(0),(1);
883  SELECT * FROM t1 LEFT JOIN (SELECT abs(1) AS y FROM t1) ON x WHERE NOT(y='a');
884} {1 1 1 1}
885do_execsql_test join-17.110 {
886  SELECT * FROM t1 LEFT JOIN (SELECT abs(1)+2 AS y FROM t1) ON x
887   WHERE NOT(y='a');
888} {1 3 1 3}
889
890#-------------------------------------------------------------------------
891reset_db
892do_execsql_test join-18.1 {
893  CREATE TABLE t0(a);
894  CREATE TABLE t1(b);
895  CREATE VIEW v0 AS SELECT a FROM t1 LEFT JOIN t0;
896  INSERT INTO t1 VALUES (1);
897} {}
898
899do_execsql_test join-18.2 {
900  SELECT * FROM v0 WHERE NOT(v0.a IS FALSE);
901} {{}}
902
903do_execsql_test join-18.3 {
904  SELECT * FROM t1 LEFT JOIN t0 WHERE NOT(a IS FALSE);
905} {1 {}}
906
907do_execsql_test join-18.4 {
908  SELECT NOT(v0.a IS FALSE) FROM v0
909} {1}
910
911#-------------------------------------------------------------------------
912reset_db
913do_execsql_test join-19.0 {
914  CREATE TABLE t1(a);
915  CREATE TABLE t2(b);
916  INSERT INTO t1(a) VALUES(0);
917  CREATE VIEW v0(c) AS SELECT t2.b FROM t1 LEFT JOIN t2;
918}
919
920do_execsql_test join-19.1 {
921  SELECT * FROM v0 WHERE v0.c NOTNULL NOTNULL;
922} {{}}
923
924do_execsql_test join-19.2 {
925  SELECT * FROM t1 LEFT JOIN t2
926} {0 {}}
927
928do_execsql_test join-19.3 {
929  SELECT * FROM t1 LEFT JOIN t2 WHERE (b IS NOT NULL) IS NOT NULL;
930} {0 {}}
931
932do_execsql_test join-19.4 {
933  SELECT (b IS NOT NULL) IS NOT NULL FROM t1 LEFT JOIN t2
934} {1}
935
936do_execsql_test join-19.5 {
937  SELECT * FROM t1 LEFT JOIN t2 WHERE
938    (b IS NOT NULL AND b IS NOT NULL) IS NOT NULL;
939} {0 {}}
940
941# 2019-11-02 ticket 623eff57e76d45f6
942# The optimization of exclusing the WHERE expression of a partial index
943# from the WHERE clause of the query if the index is used does not work
944# of the table of the index is the right-hand table of a LEFT JOIN.
945#
946db close
947sqlite3 db :memory:
948do_execsql_test join-20.1 {
949  CREATE TABLE t1(c1);
950  CREATE TABLE t0(c0);
951  INSERT INTO t0(c0) VALUES (0);
952  SELECT * FROM t0 LEFT JOIN t1 WHERE NULL IN (c1);
953} {}
954do_execsql_test join-20.2 {
955  CREATE INDEX t1x ON t1(0) WHERE NULL IN (c1);
956  SELECT * FROM t0 LEFT JOIN t1 WHERE NULL IN (c1);
957} {}
958
959# 2019-11-30 ticket 7f39060a24b47353
960# Do not allow a WHERE clause term to qualify a partial index on the
961# right table of a LEFT JOIN.
962#
963do_execsql_test join-21.10 {
964  DROP TABLE t0;
965  DROP TABLE t1;
966  CREATE TABLE t0(aa);
967  CREATE TABLE t1(bb);
968  INSERT INTO t0(aa) VALUES (1);
969  INSERT INTO t1(bb) VALUES (1);
970  SELECT 11, * FROM t1 LEFT JOIN t0 WHERE aa ISNULL;
971  SELECT 12, * FROM t1 LEFT JOIN t0 WHERE +aa ISNULL;
972  SELECT 13, * FROM t1 LEFT JOIN t0 ON aa ISNULL;
973  SELECT 14, * FROM t1 LEFT JOIN t0 ON +aa ISNULL;
974  CREATE INDEX i0 ON t0(aa) WHERE aa ISNULL;
975  SELECT 21, * FROM t1 LEFT JOIN t0 WHERE aa ISNULL;
976  SELECT 22, * FROM t1 LEFT JOIN t0 WHERE +aa ISNULL;
977  SELECT 23, * FROM t1 LEFT JOIN t0 ON aa ISNULL;
978  SELECT 24, * FROM t1 LEFT JOIN t0 ON +aa ISNULL;
979} {13 1 {} 14 1 {} 23 1 {} 24 1 {}}
980
981# 2019-12-18 problem with a LEFT JOIN where the RHS is a view.
982# Detected by Yongheng and Rui.
983# Follows from the optimization attempt of check-in 41c27bc0ff1d3135
984# on 2017-04-18
985#
986reset_db
987do_execsql_test join-22.10 {
988  CREATE TABLE t0(a, b);
989  CREATE INDEX t0a ON t0(a);
990  INSERT INTO t0 VALUES(10,10),(10,11),(10,12);
991  SELECT DISTINCT c FROM t0 LEFT JOIN (SELECT a+1 AS c FROM t0) ORDER BY c ;
992} {11}
993
994# 2019-12-22 ticket 7929c1efb2d67e98
995#
996reset_db
997ifcapable vtab {
998do_execsql_test join-23.10 {
999  CREATE TABLE t0(c0);
1000  INSERT INTO t0(c0) VALUES(123);
1001  CREATE VIEW v0(c0) AS SELECT 0 GROUP BY 1;
1002  SELECT t0.c0, v0.c0, vt0.name
1003   FROM v0, t0 LEFT JOIN pragma_table_info('t0') AS vt0
1004     ON vt0.name LIKE 'c0'
1005   WHERE v0.c0 == 0;
1006} {123 0 c0}
1007}
1008
1009#-------------------------------------------------------------------------
1010reset_db
1011do_execsql_test join-24.1 {
1012  CREATE TABLE t1(a PRIMARY KEY, x);
1013  CREATE TABLE t2(b INT);
1014  CREATE INDEX t1aa ON t1(a, a);
1015
1016  INSERT INTO t1 VALUES('abc', 'def');
1017  INSERT INTO t2 VALUES(1);
1018}
1019
1020do_execsql_test join-24.2 {
1021  SELECT * FROM t2 JOIN t1 WHERE a='abc' AND x='def';
1022} {1 abc def}
1023do_execsql_test join-24.3 {
1024  SELECT * FROM t2 JOIN t1 WHERE a='abc' AND x='abc';
1025} {}
1026
1027do_execsql_test join-24.2 {
1028  SELECT * FROM t2 LEFT JOIN t1 ON a=0 WHERE (x='x' OR x IS NULL);
1029} {1 {} {}}
1030
1031# 2020-09-30 ticket 66e4b0e271c47145
1032# The query flattener inserts an "expr AND expr" expression as a substitution
1033# for the column of a view where that view column is part of an ON expression
1034# of a LEFT JOIN.
1035#
1036reset_db
1037do_execsql_test join-25.1 {
1038  CREATE TABLE t0(c0 INT);
1039  CREATE VIEW v0 AS SELECT (NULL AND 5) as c0 FROM t0;
1040  INSERT INTO t0(c0) VALUES (NULL);
1041  SELECT count(*)  FROM v0 LEFT JOIN t0 ON v0.c0;
1042} {1}
1043
1044# 2022-04-21 Parser issue detected by dbsqlfuzz
1045#
1046reset_db
1047do_catchsql_test join-26.1 {
1048  CREATE TABLE t4(a,b);
1049  CREATE TABLE t5(a,c);
1050  CREATE TABLE t6(a,d);
1051  SELECT * FROM t5 JOIN ((t4 JOIN (t5 JOIN t6)) t7);
1052} {/1 {.*}/}
1053
1054finish_test
1055