13f1e9e00Sdrh# 2002-05-24 2ad2d8307Sdrh# 3ad2d8307Sdrh# The author disclaims copyright to this source code. In place of 4ad2d8307Sdrh# a legal notice, here is a blessing: 5ad2d8307Sdrh# 6ad2d8307Sdrh# May you do good and not evil. 7ad2d8307Sdrh# May you find forgiveness for yourself and forgive others. 8ad2d8307Sdrh# May you share freely, never taking more than you give. 9ad2d8307Sdrh# 10ad2d8307Sdrh#*********************************************************************** 11ad2d8307Sdrh# This file implements regression tests for SQLite library. 12ad2d8307Sdrh# 13ad2d8307Sdrh# This file implements tests for joins, including outer joins. 14ad2d8307Sdrh# 15ad2d8307Sdrh 16ad2d8307Sdrhset testdir [file dirname $argv0] 17ad2d8307Sdrhsource $testdir/tester.tcl 18ad2d8307Sdrh 19ad2d8307Sdrhdo_test join-1.1 { 20ad2d8307Sdrh execsql { 21ad2d8307Sdrh CREATE TABLE t1(a,b,c); 22ad2d8307Sdrh INSERT INTO t1 VALUES(1,2,3); 23ad2d8307Sdrh INSERT INTO t1 VALUES(2,3,4); 24ad2d8307Sdrh INSERT INTO t1 VALUES(3,4,5); 25ad2d8307Sdrh SELECT * FROM t1; 26ad2d8307Sdrh } 27ad2d8307Sdrh} {1 2 3 2 3 4 3 4 5} 28ad2d8307Sdrhdo_test join-1.2 { 29ad2d8307Sdrh execsql { 30ad2d8307Sdrh CREATE TABLE t2(b,c,d); 31ad2d8307Sdrh INSERT INTO t2 VALUES(1,2,3); 32ad2d8307Sdrh INSERT INTO t2 VALUES(2,3,4); 33ad2d8307Sdrh INSERT INTO t2 VALUES(3,4,5); 34ad2d8307Sdrh SELECT * FROM t2; 35ad2d8307Sdrh } 36ad2d8307Sdrh} {1 2 3 2 3 4 3 4 5} 37ad2d8307Sdrh 3871607c77Sdrh# A FROM clause of the form: "<table>, <table> ON <expr>" is not 3971607c77Sdrh# allowed by the SQLite syntax diagram, nor by any other SQL database 4071607c77Sdrh# engine that we are aware of. Nevertheless, historic versions of 4171607c77Sdrh# SQLite have allowed it. We need to continue to support it moving 4271607c77Sdrh# forward to prevent breakage of legacy applications. Though, we will 4371607c77Sdrh# not advertise it as being supported. 4471607c77Sdrh# 4571607c77Sdrhdo_execsql_test join-1.2.1 { 4671607c77Sdrh SELECT t1.rowid, t2.rowid, '|' FROM t1, t2 ON t1.a=t2.b; 4771607c77Sdrh} {1 1 | 2 2 | 3 3 |} 4871607c77Sdrh 49ad2d8307Sdrhdo_test join-1.3 { 50ad2d8307Sdrh execsql2 { 51ad2d8307Sdrh SELECT * FROM t1 NATURAL JOIN t2; 52ad2d8307Sdrh } 5347a6db2bSdrh} {a 1 b 2 c 3 d 4 a 2 b 3 c 4 d 5} 54195e6967Sdrhdo_test join-1.3.1 { 55195e6967Sdrh execsql2 { 56195e6967Sdrh SELECT * FROM t2 NATURAL JOIN t1; 57195e6967Sdrh } 5847a6db2bSdrh} {b 2 c 3 d 4 a 1 b 3 c 4 d 5 a 2} 59030530deSdrhdo_test join-1.3.2 { 60030530deSdrh execsql2 { 61030530deSdrh SELECT * FROM t2 AS x NATURAL JOIN t1; 62030530deSdrh } 63030530deSdrh} {b 2 c 3 d 4 a 1 b 3 c 4 d 5 a 2} 64030530deSdrhdo_test join-1.3.3 { 65030530deSdrh execsql2 { 66030530deSdrh SELECT * FROM t2 NATURAL JOIN t1 AS y; 67030530deSdrh } 68030530deSdrh} {b 2 c 3 d 4 a 1 b 3 c 4 d 5 a 2} 69355ef361Sdrhdo_test join-1.3.4 { 70355ef361Sdrh execsql { 71355ef361Sdrh SELECT b FROM t1 NATURAL JOIN t2; 72355ef361Sdrh } 73355ef361Sdrh} {2 3} 74da55c48aSdrh 75da55c48aSdrh# ticket #3522 76da55c48aSdrhdo_test join-1.3.5 { 77da55c48aSdrh execsql2 { 78da55c48aSdrh SELECT t2.* FROM t2 NATURAL JOIN t1 79da55c48aSdrh } 80da55c48aSdrh} {b 2 c 3 d 4 b 3 c 4 d 5} 81da55c48aSdrhdo_test join-1.3.6 { 82da55c48aSdrh execsql2 { 83da55c48aSdrh SELECT xyzzy.* FROM t2 AS xyzzy NATURAL JOIN t1 84da55c48aSdrh } 85da55c48aSdrh} {b 2 c 3 d 4 b 3 c 4 d 5} 86da55c48aSdrhdo_test join-1.3.7 { 87da55c48aSdrh execsql2 { 88da55c48aSdrh SELECT t1.* FROM t2 NATURAL JOIN t1 89da55c48aSdrh } 90da55c48aSdrh} {a 1 b 2 c 3 a 2 b 3 c 4} 91da55c48aSdrhdo_test join-1.3.8 { 92da55c48aSdrh execsql2 { 93da55c48aSdrh SELECT xyzzy.* FROM t2 NATURAL JOIN t1 AS xyzzy 94da55c48aSdrh } 95da55c48aSdrh} {a 1 b 2 c 3 a 2 b 3 c 4} 96da55c48aSdrhdo_test join-1.3.9 { 97da55c48aSdrh execsql2 { 98da55c48aSdrh SELECT aaa.*, bbb.* FROM t2 AS aaa NATURAL JOIN t1 AS bbb 99da55c48aSdrh } 100da55c48aSdrh} {b 2 c 3 d 4 a 1 b 2 c 3 b 3 c 4 d 5 a 2 b 3 c 4} 101da55c48aSdrhdo_test join-1.3.10 { 102da55c48aSdrh execsql2 { 103da55c48aSdrh SELECT t1.*, t2.* FROM t2 NATURAL JOIN t1 104da55c48aSdrh } 105da55c48aSdrh} {a 1 b 2 c 3 b 2 c 3 d 4 a 2 b 3 c 4 b 3 c 4 d 5} 106da55c48aSdrh 107da55c48aSdrh 108030530deSdrhdo_test join-1.4.1 { 109ad2d8307Sdrh execsql2 { 110ad2d8307Sdrh SELECT * FROM t1 INNER JOIN t2 USING(b,c); 111ad2d8307Sdrh } 11247a6db2bSdrh} {a 1 b 2 c 3 d 4 a 2 b 3 c 4 d 5} 113030530deSdrhdo_test join-1.4.2 { 114030530deSdrh execsql2 { 115030530deSdrh SELECT * FROM t1 AS x INNER JOIN t2 USING(b,c); 116030530deSdrh } 117030530deSdrh} {a 1 b 2 c 3 d 4 a 2 b 3 c 4 d 5} 118030530deSdrhdo_test join-1.4.3 { 119030530deSdrh execsql2 { 120030530deSdrh SELECT * FROM t1 INNER JOIN t2 AS y USING(b,c); 121030530deSdrh } 122030530deSdrh} {a 1 b 2 c 3 d 4 a 2 b 3 c 4 d 5} 123030530deSdrhdo_test join-1.4.4 { 124030530deSdrh execsql2 { 125030530deSdrh SELECT * FROM t1 AS x INNER JOIN t2 AS y USING(b,c); 126030530deSdrh } 127030530deSdrh} {a 1 b 2 c 3 d 4 a 2 b 3 c 4 d 5} 128873fac0cSdrhdo_test join-1.4.5 { 129873fac0cSdrh execsql { 130873fac0cSdrh SELECT b FROM t1 JOIN t2 USING(b); 131873fac0cSdrh } 132873fac0cSdrh} {2 3} 133da55c48aSdrh 134da55c48aSdrh# Ticket #3522 135da55c48aSdrhdo_test join-1.4.6 { 136da55c48aSdrh execsql2 { 137da55c48aSdrh SELECT t1.* FROM t1 JOIN t2 USING(b); 138da55c48aSdrh } 139da55c48aSdrh} {a 1 b 2 c 3 a 2 b 3 c 4} 140da55c48aSdrhdo_test join-1.4.7 { 141da55c48aSdrh execsql2 { 142da55c48aSdrh SELECT t2.* FROM t1 JOIN t2 USING(b); 143da55c48aSdrh } 144da55c48aSdrh} {b 2 c 3 d 4 b 3 c 4 d 5} 145da55c48aSdrh 146ad2d8307Sdrhdo_test join-1.5 { 147ad2d8307Sdrh execsql2 { 148ad2d8307Sdrh SELECT * FROM t1 INNER JOIN t2 USING(b); 149ad2d8307Sdrh } 15047a6db2bSdrh} {a 1 b 2 c 3 c 3 d 4 a 2 b 3 c 4 c 4 d 5} 151ad2d8307Sdrhdo_test join-1.6 { 152ad2d8307Sdrh execsql2 { 153ad2d8307Sdrh SELECT * FROM t1 INNER JOIN t2 USING(c); 154ad2d8307Sdrh } 15547a6db2bSdrh} {a 1 b 2 c 3 b 2 d 4 a 2 b 3 c 4 b 3 d 5} 156ad2d8307Sdrhdo_test join-1.7 { 157ad2d8307Sdrh execsql2 { 158ad2d8307Sdrh SELECT * FROM t1 INNER JOIN t2 USING(c,b); 159ad2d8307Sdrh } 16047a6db2bSdrh} {a 1 b 2 c 3 d 4 a 2 b 3 c 4 d 5} 161ad2d8307Sdrh 162195e6967Sdrhdo_test join-1.8 { 163195e6967Sdrh execsql { 164195e6967Sdrh SELECT * FROM t1 NATURAL CROSS JOIN t2; 165195e6967Sdrh } 166195e6967Sdrh} {1 2 3 4 2 3 4 5} 167195e6967Sdrhdo_test join-1.9 { 168195e6967Sdrh execsql { 169195e6967Sdrh SELECT * FROM t1 CROSS JOIN t2 USING(b,c); 170195e6967Sdrh } 171195e6967Sdrh} {1 2 3 4 2 3 4 5} 172195e6967Sdrhdo_test join-1.10 { 173195e6967Sdrh execsql { 174195e6967Sdrh SELECT * FROM t1 NATURAL INNER JOIN t2; 175195e6967Sdrh } 176195e6967Sdrh} {1 2 3 4 2 3 4 5} 177195e6967Sdrhdo_test join-1.11 { 178195e6967Sdrh execsql { 179195e6967Sdrh SELECT * FROM t1 INNER JOIN t2 USING(b,c); 180195e6967Sdrh } 181195e6967Sdrh} {1 2 3 4 2 3 4 5} 182195e6967Sdrhdo_test join-1.12 { 183195e6967Sdrh execsql { 184195e6967Sdrh SELECT * FROM t1 natural inner join t2; 185195e6967Sdrh } 186195e6967Sdrh} {1 2 3 4 2 3 4 5} 1873e8c37e7Sdanielk1977 1883e8c37e7Sdanielk1977ifcapable subquery { 189195e6967Sdrh do_test join-1.13 { 190195e6967Sdrh execsql2 { 191195e6967Sdrh SELECT * FROM t1 NATURAL JOIN 192195e6967Sdrh (SELECT b as 'c', c as 'd', d as 'e' FROM t2) as t3 193195e6967Sdrh } 19447a6db2bSdrh } {a 1 b 2 c 3 d 4 e 5} 195195e6967Sdrh do_test join-1.14 { 196195e6967Sdrh execsql2 { 197195e6967Sdrh SELECT * FROM (SELECT b as 'c', c as 'd', d as 'e' FROM t2) as 'tx' 198195e6967Sdrh NATURAL JOIN t1 199195e6967Sdrh } 20047a6db2bSdrh } {c 3 d 4 e 5 a 1 b 2} 2013e8c37e7Sdanielk1977} 202195e6967Sdrh 203195e6967Sdrhdo_test join-1.15 { 204195e6967Sdrh execsql { 205195e6967Sdrh CREATE TABLE t3(c,d,e); 206195e6967Sdrh INSERT INTO t3 VALUES(2,3,4); 207195e6967Sdrh INSERT INTO t3 VALUES(3,4,5); 208195e6967Sdrh INSERT INTO t3 VALUES(4,5,6); 209195e6967Sdrh SELECT * FROM t3; 210195e6967Sdrh } 211195e6967Sdrh} {2 3 4 3 4 5 4 5 6} 212195e6967Sdrhdo_test join-1.16 { 213195e6967Sdrh execsql { 214195e6967Sdrh SELECT * FROM t1 natural join t2 natural join t3; 215195e6967Sdrh } 216195e6967Sdrh} {1 2 3 4 5 2 3 4 5 6} 217195e6967Sdrhdo_test join-1.17 { 218195e6967Sdrh execsql2 { 219195e6967Sdrh SELECT * FROM t1 natural join t2 natural join t3; 220195e6967Sdrh } 22147a6db2bSdrh} {a 1 b 2 c 3 d 4 e 5 a 2 b 3 c 4 d 5 e 6} 222195e6967Sdrhdo_test join-1.18 { 223195e6967Sdrh execsql { 224195e6967Sdrh CREATE TABLE t4(d,e,f); 225195e6967Sdrh INSERT INTO t4 VALUES(2,3,4); 226195e6967Sdrh INSERT INTO t4 VALUES(3,4,5); 227195e6967Sdrh INSERT INTO t4 VALUES(4,5,6); 228195e6967Sdrh SELECT * FROM t4; 229195e6967Sdrh } 230195e6967Sdrh} {2 3 4 3 4 5 4 5 6} 23147a6db2bSdrhdo_test join-1.19.1 { 232195e6967Sdrh execsql { 233195e6967Sdrh SELECT * FROM t1 natural join t2 natural join t4; 234195e6967Sdrh } 235195e6967Sdrh} {1 2 3 4 5 6} 23647a6db2bSdrhdo_test join-1.19.2 { 237195e6967Sdrh execsql2 { 238195e6967Sdrh SELECT * FROM t1 natural join t2 natural join t4; 239195e6967Sdrh } 24047a6db2bSdrh} {a 1 b 2 c 3 d 4 e 5 f 6} 241195e6967Sdrhdo_test join-1.20 { 242195e6967Sdrh execsql { 243195e6967Sdrh SELECT * FROM t1 natural join t2 natural join t3 WHERE t1.a=1 244195e6967Sdrh } 245195e6967Sdrh} {1 2 3 4 5} 246195e6967Sdrh 247ad2d8307Sdrhdo_test join-2.1 { 248ad2d8307Sdrh execsql { 249ad2d8307Sdrh SELECT * FROM t1 NATURAL LEFT JOIN t2; 250ad2d8307Sdrh } 251ad2d8307Sdrh} {1 2 3 4 2 3 4 5 3 4 5 {}} 252da55c48aSdrh 253825ecf9cSdrh# EVIDENCE-OF: R-52129-05406 you can say things like "OUTER LEFT NATURAL 254825ecf9cSdrh# JOIN" which means the same as "NATURAL LEFT OUTER JOIN". 255825ecf9cSdrhdo_test join-2.1b { 256825ecf9cSdrh execsql { 257825ecf9cSdrh SELECT * FROM t1 OUTER LEFT NATURAL JOIN t2; 258825ecf9cSdrh } 259825ecf9cSdrh} {1 2 3 4 2 3 4 5 3 4 5 {}} 260825ecf9cSdrhdo_test join-2.1c { 261825ecf9cSdrh execsql { 262825ecf9cSdrh SELECT * FROM t1 NATURAL LEFT OUTER JOIN t2; 263825ecf9cSdrh } 264825ecf9cSdrh} {1 2 3 4 2 3 4 5 3 4 5 {}} 265825ecf9cSdrh 266da55c48aSdrh# ticket #3522 267da55c48aSdrhdo_test join-2.1.1 { 268da55c48aSdrh execsql2 { 269da55c48aSdrh SELECT * FROM t1 NATURAL LEFT JOIN t2; 270da55c48aSdrh } 271da55c48aSdrh} {a 1 b 2 c 3 d 4 a 2 b 3 c 4 d 5 a 3 b 4 c 5 d {}} 272da55c48aSdrhdo_test join-2.1.2 { 273da55c48aSdrh execsql2 { 274da55c48aSdrh SELECT t1.* FROM t1 NATURAL LEFT JOIN t2; 275da55c48aSdrh } 276da55c48aSdrh} {a 1 b 2 c 3 a 2 b 3 c 4 a 3 b 4 c 5} 277da55c48aSdrhdo_test join-2.1.3 { 278da55c48aSdrh execsql2 { 279da55c48aSdrh SELECT t2.* FROM t1 NATURAL LEFT JOIN t2; 280da55c48aSdrh } 281da55c48aSdrh} {b 2 c 3 d 4 b 3 c 4 d 5 b {} c {} d {}} 282da55c48aSdrh 283195e6967Sdrhdo_test join-2.2 { 284195e6967Sdrh execsql { 285195e6967Sdrh SELECT * FROM t2 NATURAL LEFT OUTER JOIN t1; 286195e6967Sdrh } 287195e6967Sdrh} {1 2 3 {} 2 3 4 1 3 4 5 2} 288a76ac88aSdrh 289a76ac88aSdrh#do_test join-2.3 { 290a76ac88aSdrh# catchsql { 291a76ac88aSdrh# SELECT * FROM t1 NATURAL RIGHT OUTER JOIN t2; 292a76ac88aSdrh# } 293a76ac88aSdrh#} {1 {RIGHT and FULL OUTER JOINs are not currently supported}} 294a76ac88aSdrh 2953b167c75Sdrhdo_test join-2.4 { 2963b167c75Sdrh execsql { 2973b167c75Sdrh SELECT * FROM t1 LEFT JOIN t2 ON t1.a=t2.d 2983b167c75Sdrh } 2993b167c75Sdrh} {1 2 3 {} {} {} 2 3 4 {} {} {} 3 4 5 1 2 3} 3003b167c75Sdrhdo_test join-2.5 { 3013b167c75Sdrh execsql { 3023b167c75Sdrh SELECT * FROM t1 LEFT JOIN t2 ON t1.a=t2.d WHERE t1.a>1 3033b167c75Sdrh } 3043b167c75Sdrh} {2 3 4 {} {} {} 3 4 5 1 2 3} 3053b167c75Sdrhdo_test join-2.6 { 3063b167c75Sdrh execsql { 3073b167c75Sdrh SELECT * FROM t1 LEFT JOIN t2 ON t1.a=t2.d WHERE t2.b IS NULL OR t2.b>1 3083b167c75Sdrh } 3093b167c75Sdrh} {1 2 3 {} {} {} 2 3 4 {} {} {}} 310195e6967Sdrh 311195e6967Sdrhdo_test join-3.1 { 312195e6967Sdrh catchsql { 313195e6967Sdrh SELECT * FROM t1 NATURAL JOIN t2 ON t1.a=t2.b; 314195e6967Sdrh } 315195e6967Sdrh} {1 {a NATURAL join may not have an ON or USING clause}} 316195e6967Sdrhdo_test join-3.2 { 317195e6967Sdrh catchsql { 318195e6967Sdrh SELECT * FROM t1 NATURAL JOIN t2 USING(b); 319195e6967Sdrh } 320195e6967Sdrh} {1 {a NATURAL join may not have an ON or USING clause}} 321195e6967Sdrhdo_test join-3.3 { 322195e6967Sdrh catchsql { 323195e6967Sdrh SELECT * FROM t1 JOIN t2 ON t1.a=t2.b USING(b); 324195e6967Sdrh } 325d44f8b23Sdrh} {1 {near "USING": syntax error}} 326a9671a22Sdrhdo_test join-3.4.1 { 327195e6967Sdrh catchsql { 328195e6967Sdrh SELECT * FROM t1 JOIN t2 USING(a); 329195e6967Sdrh } 330195e6967Sdrh} {1 {cannot join using column a - column not present in both tables}} 331a9671a22Sdrhdo_test join-3.4.2 { 332a9671a22Sdrh catchsql { 333a9671a22Sdrh SELECT * FROM t1 JOIN t2 USING(d); 334a9671a22Sdrh } 335a9671a22Sdrh} {1 {cannot join using column d - column not present in both tables}} 336195e6967Sdrhdo_test join-3.5 { 337bd1a0a4fSdanielk1977 catchsql { SELECT * FROM t1 USING(a) } 338bd1a0a4fSdanielk1977} {1 {a JOIN clause is required before USING}} 339195e6967Sdrhdo_test join-3.6 { 340195e6967Sdrh catchsql { 341195e6967Sdrh SELECT * FROM t1 JOIN t2 ON t3.a=t2.b; 342195e6967Sdrh } 343195e6967Sdrh} {1 {no such column: t3.a}} 344825ecf9cSdrh 345825ecf9cSdrh# EVIDENCE-OF: R-47973-48020 you cannot say "INNER OUTER JOIN", because 346825ecf9cSdrh# that would be contradictory. 347195e6967Sdrhdo_test join-3.7 { 348195e6967Sdrh catchsql { 349195e6967Sdrh SELECT * FROM t1 INNER OUTER JOIN t2; 350195e6967Sdrh } 3510879d5f9Sdrh} {1 {unknown join type: INNER OUTER}} 352a9671a22Sdrhdo_test join-3.8 { 353a9671a22Sdrh catchsql { 354a9671a22Sdrh SELECT * FROM t1 INNER OUTER CROSS JOIN t2; 355a9671a22Sdrh } 3560879d5f9Sdrh} {1 {unknown join type: INNER OUTER CROSS}} 357a9671a22Sdrhdo_test join-3.9 { 358a9671a22Sdrh catchsql { 359a9671a22Sdrh SELECT * FROM t1 OUTER NATURAL INNER JOIN t2; 360a9671a22Sdrh } 3610879d5f9Sdrh} {1 {unknown join type: OUTER NATURAL INNER}} 362a9671a22Sdrhdo_test join-3.10 { 363195e6967Sdrh catchsql { 3645ad1a6c8Sdrh SELECT * FROM t1 LEFT BOGUS JOIN t2; 365195e6967Sdrh } 3660879d5f9Sdrh} {1 {unknown join type: LEFT BOGUS}} 367a9671a22Sdrhdo_test join-3.11 { 368a9671a22Sdrh catchsql { 369a9671a22Sdrh SELECT * FROM t1 INNER BOGUS CROSS JOIN t2; 370a9671a22Sdrh } 3710879d5f9Sdrh} {1 {unknown join type: INNER BOGUS CROSS}} 372a9671a22Sdrhdo_test join-3.12 { 373a9671a22Sdrh catchsql { 374a9671a22Sdrh SELECT * FROM t1 NATURAL AWK SED JOIN t2; 375a9671a22Sdrh } 3760879d5f9Sdrh} {1 {unknown join type: NATURAL AWK SED}} 377195e6967Sdrh 378f1351b67Sdrhdo_test join-4.1 { 379f1351b67Sdrh execsql { 380f1351b67Sdrh BEGIN; 381f1351b67Sdrh CREATE TABLE t5(a INTEGER PRIMARY KEY); 382f1351b67Sdrh CREATE TABLE t6(a INTEGER); 383f1351b67Sdrh INSERT INTO t6 VALUES(NULL); 384f1351b67Sdrh INSERT INTO t6 VALUES(NULL); 385f1351b67Sdrh INSERT INTO t6 SELECT * FROM t6; 386f1351b67Sdrh INSERT INTO t6 SELECT * FROM t6; 387f1351b67Sdrh INSERT INTO t6 SELECT * FROM t6; 388f1351b67Sdrh INSERT INTO t6 SELECT * FROM t6; 389f1351b67Sdrh INSERT INTO t6 SELECT * FROM t6; 390f1351b67Sdrh INSERT INTO t6 SELECT * FROM t6; 391f1351b67Sdrh COMMIT; 392f1351b67Sdrh } 393f1351b67Sdrh execsql { 394f1351b67Sdrh SELECT * FROM t6 NATURAL JOIN t5; 395f1351b67Sdrh } 396f1351b67Sdrh} {} 397f1351b67Sdrhdo_test join-4.2 { 398f1351b67Sdrh execsql { 399f1351b67Sdrh SELECT * FROM t6, t5 WHERE t6.a<t5.a; 400f1351b67Sdrh } 401f1351b67Sdrh} {} 402f1351b67Sdrhdo_test join-4.3 { 403f1351b67Sdrh execsql { 404f1351b67Sdrh SELECT * FROM t6, t5 WHERE t6.a>t5.a; 405f1351b67Sdrh } 406f1351b67Sdrh} {} 407f1351b67Sdrhdo_test join-4.4 { 408f1351b67Sdrh execsql { 409f1351b67Sdrh UPDATE t6 SET a='xyz'; 410f1351b67Sdrh SELECT * FROM t6 NATURAL JOIN t5; 411f1351b67Sdrh } 412f1351b67Sdrh} {} 413f1351b67Sdrhdo_test join-4.6 { 414f1351b67Sdrh execsql { 415f1351b67Sdrh SELECT * FROM t6, t5 WHERE t6.a<t5.a; 416f1351b67Sdrh } 417f1351b67Sdrh} {} 418f1351b67Sdrhdo_test join-4.7 { 419f1351b67Sdrh execsql { 420f1351b67Sdrh SELECT * FROM t6, t5 WHERE t6.a>t5.a; 421f1351b67Sdrh } 422f1351b67Sdrh} {} 423f1351b67Sdrhdo_test join-4.8 { 424f1351b67Sdrh execsql { 425f1351b67Sdrh UPDATE t6 SET a=1; 426f1351b67Sdrh SELECT * FROM t6 NATURAL JOIN t5; 427f1351b67Sdrh } 428f1351b67Sdrh} {} 429f1351b67Sdrhdo_test join-4.9 { 430f1351b67Sdrh execsql { 431f1351b67Sdrh SELECT * FROM t6, t5 WHERE t6.a<t5.a; 432f1351b67Sdrh } 433f1351b67Sdrh} {} 434f1351b67Sdrhdo_test join-4.10 { 435f1351b67Sdrh execsql { 436f1351b67Sdrh SELECT * FROM t6, t5 WHERE t6.a>t5.a; 437f1351b67Sdrh } 438f1351b67Sdrh} {} 439f1351b67Sdrh 440c8f8b632Sdrhdo_test join-5.1 { 441c8f8b632Sdrh execsql { 442c8f8b632Sdrh BEGIN; 443c8f8b632Sdrh create table centros (id integer primary key, centro); 444c8f8b632Sdrh INSERT INTO centros VALUES(1,'xxx'); 445c8f8b632Sdrh create table usuarios (id integer primary key, nombre, apellidos, 446c8f8b632Sdrh idcentro integer); 447c8f8b632Sdrh INSERT INTO usuarios VALUES(1,'a','aa',1); 448c8f8b632Sdrh INSERT INTO usuarios VALUES(2,'b','bb',1); 449c8f8b632Sdrh INSERT INTO usuarios VALUES(3,'c','cc',NULL); 450c8f8b632Sdrh create index idcentro on usuarios (idcentro); 451c8f8b632Sdrh END; 452c8f8b632Sdrh select usuarios.id, usuarios.nombre, centros.centro from 453c8f8b632Sdrh usuarios left outer join centros on usuarios.idcentro = centros.id; 454c8f8b632Sdrh } 455c8f8b632Sdrh} {1 a xxx 2 b xxx 3 c {}} 456ad2d8307Sdrh 45750cceb36Sdrh# A test for ticket #247. 45850cceb36Sdrh# 45950cceb36Sdrhdo_test join-7.1 { 4607d44b22dSdrh sqlite3_db_config db SQLITE_DBCONFIG_DQS_DML 1 46150cceb36Sdrh execsql { 46250cceb36Sdrh CREATE TABLE t7 (x, y); 46350cceb36Sdrh INSERT INTO t7 VALUES ("pa1", 1); 46450cceb36Sdrh INSERT INTO t7 VALUES ("pa2", NULL); 46550cceb36Sdrh INSERT INTO t7 VALUES ("pa3", NULL); 46650cceb36Sdrh INSERT INTO t7 VALUES ("pa4", 2); 46750cceb36Sdrh INSERT INTO t7 VALUES ("pa30", 131); 46850cceb36Sdrh INSERT INTO t7 VALUES ("pa31", 130); 46950cceb36Sdrh INSERT INTO t7 VALUES ("pa28", NULL); 47050cceb36Sdrh 47150cceb36Sdrh CREATE TABLE t8 (a integer primary key, b); 47250cceb36Sdrh INSERT INTO t8 VALUES (1, "pa1"); 47350cceb36Sdrh INSERT INTO t8 VALUES (2, "pa4"); 47450cceb36Sdrh INSERT INTO t8 VALUES (3, NULL); 47550cceb36Sdrh INSERT INTO t8 VALUES (4, NULL); 47650cceb36Sdrh INSERT INTO t8 VALUES (130, "pa31"); 47750cceb36Sdrh INSERT INTO t8 VALUES (131, "pa30"); 47850cceb36Sdrh 47950cceb36Sdrh SELECT coalesce(t8.a,999) from t7 LEFT JOIN t8 on y=a; 48050cceb36Sdrh } 48150cceb36Sdrh} {1 999 999 2 131 130 999} 48250cceb36Sdrh 4838af4d3acSdrh# Make sure a left join where the right table is really a view that 4848af4d3acSdrh# is itself a join works right. Ticket #306. 4858af4d3acSdrh# 4860fa8ddbdSdanielk1977ifcapable view { 4878af4d3acSdrhdo_test join-8.1 { 4888af4d3acSdrh execsql { 4898af4d3acSdrh BEGIN; 4908af4d3acSdrh CREATE TABLE t9(a INTEGER PRIMARY KEY, b); 4918af4d3acSdrh INSERT INTO t9 VALUES(1,11); 4928af4d3acSdrh INSERT INTO t9 VALUES(2,22); 4938af4d3acSdrh CREATE TABLE t10(x INTEGER PRIMARY KEY, y); 4948af4d3acSdrh INSERT INTO t10 VALUES(1,2); 4958af4d3acSdrh INSERT INTO t10 VALUES(3,3); 4968af4d3acSdrh CREATE TABLE t11(p INTEGER PRIMARY KEY, q); 4978af4d3acSdrh INSERT INTO t11 VALUES(2,111); 4988af4d3acSdrh INSERT INTO t11 VALUES(3,333); 4998af4d3acSdrh CREATE VIEW v10_11 AS SELECT x, q FROM t10, t11 WHERE t10.y=t11.p; 5008af4d3acSdrh COMMIT; 5018af4d3acSdrh SELECT * FROM t9 LEFT JOIN v10_11 ON( a=x ); 5028af4d3acSdrh } 5038af4d3acSdrh} {1 11 1 111 2 22 {} {}} 504e61b9f4fSdanielk1977ifcapable subquery { 5058af4d3acSdrh do_test join-8.2 { 5068af4d3acSdrh execsql { 5073fc673e6Sdrh SELECT * FROM t9 LEFT JOIN (SELECT x, q FROM t10, t11 WHERE t10.y=t11.p) 5083fc673e6Sdrh ON( a=x); 5093fc673e6Sdrh } 5103fc673e6Sdrh } {1 11 1 111 2 22 {} {}} 511e61b9f4fSdanielk1977} 5123fc673e6Sdrhdo_test join-8.3 { 5133fc673e6Sdrh execsql { 5148af4d3acSdrh SELECT * FROM v10_11 LEFT JOIN t9 ON( a=x ); 5158af4d3acSdrh } 5168af4d3acSdrh} {1 111 1 11 3 333 {} {}} 5172b300d5dSdrhifcapable subquery { 5182b300d5dSdrh # Constant expressions in a subquery that is the right element of a 5192b300d5dSdrh # LEFT JOIN evaluate to NULL for rows where the LEFT JOIN does not 5202b300d5dSdrh # match. Ticket #3300 5212b300d5dSdrh do_test join-8.4 { 5222b300d5dSdrh execsql { 5232b300d5dSdrh SELECT * FROM t9 LEFT JOIN (SELECT 44, p, q FROM t11) AS sub1 ON p=a 5242b300d5dSdrh } 5252b300d5dSdrh } {1 11 {} {} {} 2 22 44 2 111} 5262b300d5dSdrh} 5270fa8ddbdSdanielk1977} ;# ifcapable view 5288af4d3acSdrh 5293fc673e6Sdrh# Ticket #350 describes a scenario where LEFT OUTER JOIN does not 5303fc673e6Sdrh# function correctly if the right table in the join is really 5313fc673e6Sdrh# subquery. 5323fc673e6Sdrh# 5333fc673e6Sdrh# To test the problem, we generate the same LEFT OUTER JOIN in two 5343fc673e6Sdrh# separate selects but with on using a subquery and the other calling 5353fc673e6Sdrh# the table directly. Then connect the two SELECTs using an EXCEPT. 5363fc673e6Sdrh# Both queries should generate the same results so the answer should 5373fc673e6Sdrh# be an empty set. 5383fc673e6Sdrh# 53927c77438Sdanielk1977ifcapable compound { 5403fc673e6Sdrhdo_test join-9.1 { 5413fc673e6Sdrh execsql { 5423fc673e6Sdrh BEGIN; 5433fc673e6Sdrh CREATE TABLE t12(a,b); 5443fc673e6Sdrh INSERT INTO t12 VALUES(1,11); 5453fc673e6Sdrh INSERT INTO t12 VALUES(2,22); 5463fc673e6Sdrh CREATE TABLE t13(b,c); 5473fc673e6Sdrh INSERT INTO t13 VALUES(22,222); 5483fc673e6Sdrh COMMIT; 549e61b9f4fSdanielk1977 } 550e61b9f4fSdanielk1977} {} 551e61b9f4fSdanielk1977 552e61b9f4fSdanielk1977ifcapable subquery { 553e61b9f4fSdanielk1977 do_test join-9.1.1 { 5547bf56610Sdrh execsql { 5553fc673e6Sdrh SELECT * FROM t12 NATURAL LEFT JOIN t13 5563fc673e6Sdrh EXCEPT 5573fc673e6Sdrh SELECT * FROM t12 NATURAL LEFT JOIN (SELECT * FROM t13 WHERE b>0); 5587bf56610Sdrh } 5593fc673e6Sdrh } {} 560e61b9f4fSdanielk1977} 5610fa8ddbdSdanielk1977ifcapable view { 5623fc673e6Sdrh do_test join-9.2 { 5633fc673e6Sdrh execsql { 5643fc673e6Sdrh CREATE VIEW v13 AS SELECT * FROM t13 WHERE b>0; 5653fc673e6Sdrh SELECT * FROM t12 NATURAL LEFT JOIN t13 5663fc673e6Sdrh EXCEPT 5673fc673e6Sdrh SELECT * FROM t12 NATURAL LEFT JOIN v13; 5683fc673e6Sdrh } 5693fc673e6Sdrh } {} 5700fa8ddbdSdanielk1977} ;# ifcapable view 57127c77438Sdanielk1977} ;# ifcapable compound 5723fc673e6Sdrh 57310235605Sdanielk1977ifcapable subquery { 57441714d6fSdrh # Ticket #1697: Left Join WHERE clause terms that contain an 57541714d6fSdrh # aggregate subquery. 57641714d6fSdrh # 57741714d6fSdrh do_test join-10.1 { 57841714d6fSdrh execsql { 57941714d6fSdrh CREATE TABLE t21(a,b,c); 58041714d6fSdrh CREATE TABLE t22(p,q); 58141714d6fSdrh CREATE INDEX i22 ON t22(q); 58241714d6fSdrh SELECT a FROM t21 LEFT JOIN t22 ON b=p WHERE q= 58341714d6fSdrh (SELECT max(m.q) FROM t22 m JOIN t21 n ON n.b=m.p WHERE n.c=1); 58441714d6fSdrh } 58541714d6fSdrh } {} 58610235605Sdanielk1977 58710235605Sdanielk1977 # Test a LEFT JOIN when the right-hand side of hte join is an empty 58810235605Sdanielk1977 # sub-query. Seems fine. 58910235605Sdanielk1977 # 59010235605Sdanielk1977 do_test join-10.2 { 59110235605Sdanielk1977 execsql { 59210235605Sdanielk1977 CREATE TABLE t23(a, b, c); 59310235605Sdanielk1977 CREATE TABLE t24(a, b, c); 59410235605Sdanielk1977 INSERT INTO t23 VALUES(1, 2, 3); 59510235605Sdanielk1977 } 59610235605Sdanielk1977 execsql { 59710235605Sdanielk1977 SELECT * FROM t23 LEFT JOIN t24; 59810235605Sdanielk1977 } 59910235605Sdanielk1977 } {1 2 3 {} {} {}} 60010235605Sdanielk1977 do_test join-10.3 { 60110235605Sdanielk1977 execsql { 60210235605Sdanielk1977 SELECT * FROM t23 LEFT JOIN (SELECT * FROM t24); 60310235605Sdanielk1977 } 60410235605Sdanielk1977 } {1 2 3 {} {} {}} 60510235605Sdanielk1977 6064b2688abSdanielk1977} ;# ifcapable subquery 60741714d6fSdrh 608f7b0b0adSdan#------------------------------------------------------------------------- 609f7b0b0adSdan# The following tests are to ensure that bug b73fb0bd64 is fixed. 610f7b0b0adSdan# 611f7b0b0adSdando_test join-11.1 { 612f7b0b0adSdan drop_all_tables 613f7b0b0adSdan execsql { 614f7b0b0adSdan CREATE TABLE t1(a INTEGER PRIMARY KEY, b TEXT); 615f7b0b0adSdan CREATE TABLE t2(a INTEGER PRIMARY KEY, b TEXT); 616f7b0b0adSdan INSERT INTO t1 VALUES(1,'abc'); 617f7b0b0adSdan INSERT INTO t1 VALUES(2,'def'); 618f7b0b0adSdan INSERT INTO t2 VALUES(1,'abc'); 619f7b0b0adSdan INSERT INTO t2 VALUES(2,'def'); 620f7b0b0adSdan SELECT * FROM t1 NATURAL JOIN t2; 621f7b0b0adSdan } 622f7b0b0adSdan} {1 abc 2 def} 623f7b0b0adSdan 624f7b0b0adSdando_test join-11.2 { 625f7b0b0adSdan execsql { SELECT a FROM t1 JOIN t1 USING (a)} 626f7b0b0adSdan} {1 2} 627f7b0b0adSdando_test join-11.3 { 628f7b0b0adSdan execsql { SELECT a FROM t1 JOIN t1 AS t2 USING (a)} 629f7b0b0adSdan} {1 2} 630f7b0b0adSdando_test join-11.3 { 631f7b0b0adSdan execsql { SELECT * FROM t1 NATURAL JOIN t1 AS t2} 632f7b0b0adSdan} {1 abc 2 def} 633f7b0b0adSdando_test join-11.4 { 634f7b0b0adSdan execsql { SELECT * FROM t1 NATURAL JOIN t1 } 635f7b0b0adSdan} {1 abc 2 def} 636f7b0b0adSdan 637f7b0b0adSdando_test join-11.5 { 638f7b0b0adSdan drop_all_tables 639f7b0b0adSdan execsql { 640f7b0b0adSdan CREATE TABLE t1(a COLLATE nocase, b); 641f7b0b0adSdan CREATE TABLE t2(a, b); 642f7b0b0adSdan INSERT INTO t1 VALUES('ONE', 1); 643f7b0b0adSdan INSERT INTO t1 VALUES('two', 2); 644f7b0b0adSdan INSERT INTO t2 VALUES('one', 1); 645f7b0b0adSdan INSERT INTO t2 VALUES('two', 2); 646f7b0b0adSdan } 647f7b0b0adSdan} {} 648f7b0b0adSdando_test join-11.6 { 649f7b0b0adSdan execsql { SELECT * FROM t1 NATURAL JOIN t2 } 650f7b0b0adSdan} {ONE 1 two 2} 651f7b0b0adSdando_test join-11.7 { 652f7b0b0adSdan execsql { SELECT * FROM t2 NATURAL JOIN t1 } 653f7b0b0adSdan} {two 2} 654f7b0b0adSdan 655f7b0b0adSdando_test join-11.8 { 656f7b0b0adSdan drop_all_tables 657f7b0b0adSdan execsql { 658f7b0b0adSdan CREATE TABLE t1(a, b TEXT); 659f7b0b0adSdan CREATE TABLE t2(b INTEGER, a); 660f7b0b0adSdan INSERT INTO t1 VALUES('one', '1.0'); 661f7b0b0adSdan INSERT INTO t1 VALUES('two', '2'); 662f7b0b0adSdan INSERT INTO t2 VALUES(1, 'one'); 663f7b0b0adSdan INSERT INTO t2 VALUES(2, 'two'); 664f7b0b0adSdan } 665f7b0b0adSdan} {} 666f7b0b0adSdando_test join-11.9 { 667f7b0b0adSdan execsql { SELECT * FROM t1 NATURAL JOIN t2 } 668f7b0b0adSdan} {one 1.0 two 2} 669f7b0b0adSdando_test join-11.10 { 670f7b0b0adSdan execsql { SELECT * FROM t2 NATURAL JOIN t1 } 671f7b0b0adSdan} {1 one 2 two} 672f7b0b0adSdan 67313ef14afSdan#------------------------------------------------------------------------- 67413ef14afSdan# Test that at most 64 tables are allowed in a join. 67513ef14afSdan# 67613ef14afSdando_execsql_test join-12.1 { 67713ef14afSdan CREATE TABLE t14(x); 67813ef14afSdan INSERT INTO t14 VALUES('abcdefghij'); 67913ef14afSdan} 68013ef14afSdan 68113ef14afSdanproc jointest {tn nTbl res} { 68213ef14afSdan set sql "SELECT 1 FROM [string repeat t14, [expr $nTbl-1]] t14;" 68313ef14afSdan uplevel [list do_catchsql_test $tn $sql $res] 68413ef14afSdan} 68513ef14afSdan 68613ef14afSdanjointest join-12.2 30 {0 1} 68713ef14afSdanjointest join-12.3 63 {0 1} 68813ef14afSdanjointest join-12.4 64 {0 1} 68913ef14afSdanjointest join-12.5 65 {1 {at most 64 tables in a join}} 69013ef14afSdanjointest join-12.6 66 {1 {at most 64 tables in a join}} 69113ef14afSdanjointest join-12.7 127 {1 {at most 64 tables in a join}} 69213ef14afSdanjointest join-12.8 128 {1 {at most 64 tables in a join}} 693a6eaa635Sdan 6940ad7aa81Sdrh# As of 2019-01-17, the number of elements in a SrcList is limited 6950ad7aa81Sdrh# to 200. The following tests still run, but the answer is now 6960ad7aa81Sdrh# an SQLITE_NOMEM error. 6970ad7aa81Sdrh# 6980ad7aa81Sdrh# jointest join-12.9 1000 {1 {at most 64 tables in a join}} 6990ad7aa81Sdrh# 700a6eaa635Sdan# If SQLite is built with SQLITE_MEMDEBUG, then the huge number of realloc() 701a6eaa635Sdan# calls made by the following test cases are too time consuming to run. 702a6eaa635Sdan# Without SQLITE_MEMDEBUG, realloc() is fast enough that these are not 703a6eaa635Sdan# a problem. 7040ad7aa81Sdrh# 7050ad7aa81Sdrh# ifcapable pragma&&compileoption_diags { 7060ad7aa81Sdrh# if {[lsearch [db eval {PRAGMA compile_options}] MEMDEBUG]<0} { 7070ad7aa81Sdrh# jointest join-12.10 65534 {1 {at most 64 tables in a join}} 7080ad7aa81Sdrh# jointest join-12.11 65535 {1 {too many references to "t14": max 65535}} 7090ad7aa81Sdrh# jointest join-12.12 65536 {1 {too many references to "t14": max 65535}} 7100ad7aa81Sdrh# jointest join-12.13 65537 {1 {too many references to "t14": max 65535}} 7110ad7aa81Sdrh# } 7120ad7aa81Sdrh# } 71313ef14afSdan 71435175bf7Sdan 71535175bf7Sdan#------------------------------------------------------------------------- 71635175bf7Sdan# Test a problem with reordering tables following a LEFT JOIN. 71735175bf7Sdan# 71835175bf7Sdando_execsql_test join-13.0 { 71935175bf7Sdan CREATE TABLE aa(a); 72035175bf7Sdan CREATE TABLE bb(b); 72135175bf7Sdan CREATE TABLE cc(c); 72235175bf7Sdan 72335175bf7Sdan INSERT INTO aa VALUES(45); 72435175bf7Sdan INSERT INTO cc VALUES(45); 72535175bf7Sdan INSERT INTO cc VALUES(45); 72635175bf7Sdan} 72735175bf7Sdan 72835175bf7Sdando_execsql_test join-13.1 { 72935175bf7Sdan SELECT * FROM aa LEFT JOIN bb, cc WHERE cc.c=aa.a; 73035175bf7Sdan} {45 {} 45 45 {} 45} 73135175bf7Sdan 73235175bf7Sdan# In the following, the order of [cc] and [bb] must not be exchanged, even 73335175bf7Sdan# though this would be helpful if the query used an inner join. 73435175bf7Sdando_execsql_test join-13.2 { 73535175bf7Sdan CREATE INDEX ccc ON cc(c); 73635175bf7Sdan SELECT * FROM aa LEFT JOIN bb, cc WHERE cc.c=aa.a; 73735175bf7Sdan} {45 {} 45 45 {} 45} 73835175bf7Sdan 7393f1e9e00Sdrh# Verify that that iTable attributes the TK_IF_NULL_ROW operators in the 7403f1e9e00Sdrh# expression tree are correctly updated by the query flattener. This was 7413f1e9e00Sdrh# a bug discovered on 2017-05-22 by Mark Brand. 7423f1e9e00Sdrh# 7433f1e9e00Sdrhdo_execsql_test join-14.1 { 7443f1e9e00Sdrh SELECT * 7453f1e9e00Sdrh FROM (SELECT 1 a) AS x 7463f1e9e00Sdrh LEFT JOIN (SELECT 1, * FROM (SELECT * FROM (SELECT 1))); 7473f1e9e00Sdrh} {1 1 1} 7483f1e9e00Sdrhdo_execsql_test join-14.2 { 7493f1e9e00Sdrh SELECT * 7503f1e9e00Sdrh FROM (SELECT 1 a) AS x 7513f1e9e00Sdrh LEFT JOIN (SELECT 1, * FROM (SELECT * FROM (SELECT * FROM (SELECT 1)))) AS y 7523f1e9e00Sdrh JOIN (SELECT * FROM (SELECT 9)) AS z; 7533f1e9e00Sdrh} {1 1 1 9} 754eff0a7b2Sdrhdo_execsql_test join-14.3 { 755eff0a7b2Sdrh SELECT * 756eff0a7b2Sdrh FROM (SELECT 111) 757eff0a7b2Sdrh LEFT JOIN (SELECT cc+222, * FROM (SELECT * FROM (SELECT 333 cc))); 758eff0a7b2Sdrh} {111 555 333} 75935175bf7Sdan 7601d1fc5e3Sdrhdo_execsql_test join-14.4 { 7611d1fc5e3Sdrh DROP TABLE IF EXISTS t1; 7621d1fc5e3Sdrh CREATE TABLE t1(c PRIMARY KEY, a TEXT(10000), b TEXT(10000)); 7631d1fc5e3Sdrh SELECT * FROM (SELECT 111) LEFT JOIN (SELECT c+222 FROM t1) GROUP BY 1; 7641d1fc5e3Sdrh} {111 {}} 765521e0b6cSdrhdo_execsql_test join-14.4b { 766521e0b6cSdrh SELECT * FROM (SELECT 111) LEFT JOIN (SELECT c+222 FROM t1); 767521e0b6cSdrh} {111 {}} 7681d1fc5e3Sdrhdo_execsql_test join-14.5 { 769d1981834Sdrh SELECT * FROM (SELECT 111 AS x UNION ALL SELECT 222) 770d1981834Sdrh LEFT JOIN (SELECT c+333 AS y FROM t1) ON x=y GROUP BY 1; 771d1981834Sdrh} {111 {} 222 {}} 772521e0b6cSdrhdo_execsql_test join-14.5b { 773521e0b6cSdrh SELECT count(*) 774521e0b6cSdrh FROM (SELECT 111 AS x UNION ALL SELECT 222) 775521e0b6cSdrh LEFT JOIN (SELECT c+333 AS y FROM t1) ON x=y; 776521e0b6cSdrh} {2} 777521e0b6cSdrhdo_execsql_test join-14.5c { 778521e0b6cSdrh SELECT count(*) 779521e0b6cSdrh FROM (SELECT c+333 AS y FROM t1) 780521e0b6cSdrh RIGHT JOIN (SELECT 111 AS x UNION ALL SELECT 222) ON x=y; 781521e0b6cSdrh} {2} 782d1981834Sdrhdo_execsql_test join-14.6 { 783d1981834Sdrh SELECT * FROM (SELECT 111 AS x UNION ALL SELECT 111) 784d1981834Sdrh LEFT JOIN (SELECT c+333 AS y FROM t1) ON x=y GROUP BY 1; 785d1981834Sdrh} {111 {}} 786d1981834Sdrhdo_execsql_test join-14.7 { 787d1981834Sdrh SELECT * FROM (SELECT 111 AS x UNION ALL SELECT 111 UNION ALL SELECT 222) 788d1981834Sdrh LEFT JOIN (SELECT c+333 AS y FROM t1) ON x=y GROUP BY 1; 789d1981834Sdrh} {111 {} 222 {}} 790d1981834Sdrhdo_execsql_test join-14.8 { 791d1981834Sdrh INSERT INTO t1(c) VALUES(-111); 792d1981834Sdrh SELECT * FROM (SELECT 111 AS x UNION ALL SELECT 111 UNION ALL SELECT 222) 793d1981834Sdrh LEFT JOIN (SELECT c+333 AS y FROM t1) ON x=y GROUP BY 1; 794d1981834Sdrh} {111 {} 222 222} 795d1981834Sdrhdo_execsql_test join-14.9 { 7961d1fc5e3Sdrh DROP TABLE IF EXISTS t1; 7971d1fc5e3Sdrh CREATE TABLE t1(c PRIMARY KEY) WITHOUT ROWID; 7981d1fc5e3Sdrh SELECT * FROM (SELECT 111) LEFT JOIN (SELECT c+222 FROM t1) GROUP BY 1; 7991d1fc5e3Sdrh} {111 {}} 8001d1fc5e3Sdrh 801f43ce0b4Sdrh# Verify the fix to ticket 802f43ce0b4Sdrh# https://www.sqlite.org/src/tktview/7fde638e94287d2c948cd9389 803f43ce0b4Sdrh# 804f43ce0b4Sdrhdb close 805f43ce0b4Sdrhsqlite3 db :memory: 806f43ce0b4Sdrhdo_execsql_test join-14.10 { 807f43ce0b4Sdrh CREATE TABLE t1(a); 808f43ce0b4Sdrh INSERT INTO t1 VALUES(1),(2),(3); 809f43ce0b4Sdrh CREATE VIEW v2 AS SELECT a, 1 AS b FROM t1; 810f43ce0b4Sdrh CREATE TABLE t3(x); 811f43ce0b4Sdrh INSERT INTO t3 VALUES(2),(4); 812f43ce0b4Sdrh SELECT *, '|' FROM t3 LEFT JOIN v2 ON a=x WHERE b=1; 813f43ce0b4Sdrh} {2 2 1 |} 814f43ce0b4Sdrhdo_execsql_test join-14.11 { 815f43ce0b4Sdrh SELECT *, '|' FROM t3 LEFT JOIN v2 ON a=x WHERE b+1=x; 816f43ce0b4Sdrh} {2 2 1 |} 817f43ce0b4Sdrhdo_execsql_test join-14.12 { 818f43ce0b4Sdrh SELECT *, '|' FROM t3 LEFT JOIN v2 ON a=x ORDER BY b; 819f43ce0b4Sdrh} {4 {} {} | 2 2 1 |} 820f43ce0b4Sdrh 821bd11a2acSdan# Verify the fix for ticket 822bd11a2acSdan# https://www.sqlite.org/src/info/892fc34f173e99d8 823bd11a2acSdan# 824bd11a2acSdandb close 825bd11a2acSdansqlite3 db :memory: 826bd11a2acSdando_execsql_test join-14.20 { 827bd11a2acSdan CREATE TABLE t1(id INTEGER PRIMARY KEY); 828bd11a2acSdan CREATE TABLE t2(id INTEGER PRIMARY KEY, c2 INTEGER); 829bd11a2acSdan CREATE TABLE t3(id INTEGER PRIMARY KEY, c3 INTEGER); 830bd11a2acSdan INSERT INTO t1(id) VALUES(456); 831bd11a2acSdan INSERT INTO t3(id) VALUES(1),(2); 832bd11a2acSdan SELECT t1.id, x2.id, x3.id 833bd11a2acSdan FROM t1 834bd11a2acSdan LEFT JOIN (SELECT * FROM t2) AS x2 ON t1.id=x2.c2 835bd11a2acSdan LEFT JOIN t3 AS x3 ON x2.id=x3.c3; 836bd11a2acSdan} {456 {} {}} 837bd11a2acSdan 8382c492061Sdrh# 2018-03-24. 8392c492061Sdrh# E.Pasma discovered that the LEFT JOIN strength reduction optimization 8402c492061Sdrh# was misbehaving. The problem turned out to be that the 8412c492061Sdrh# sqlite3ExprImpliesNotNull() routine was saying that CASE expressions 8422c492061Sdrh# like 8432c492061Sdrh# 8442c492061Sdrh# CASE WHEN true THEN true ELSE x=0 END 8452c492061Sdrh# 8462c492061Sdrh# could never be true if x is NULL. The following test cases verify 8472c492061Sdrh# that this error has been resolved. 8482c492061Sdrh# 8492c492061Sdrhdb close 8502c492061Sdrhsqlite3 db :memory: 8512c492061Sdrhdo_execsql_test join-15.100 { 8522c492061Sdrh CREATE TABLE t1(a INT, b INT); 8532c492061Sdrh INSERT INTO t1 VALUES(1,2),(3,4); 8542c492061Sdrh CREATE TABLE t2(x INT, y INT); 8552c492061Sdrh SELECT *, 'x' 8562c492061Sdrh FROM t1 LEFT JOIN t2 8572c492061Sdrh WHERE CASE WHEN FALSE THEN a=x ELSE 1 END; 8582c492061Sdrh} {1 2 {} {} x 3 4 {} {} x} 859e3eff266Sdrhdo_execsql_test join-15.105 { 860e3eff266Sdrh SELECT *, 'x' 861e3eff266Sdrh FROM t1 LEFT JOIN t2 862e3eff266Sdrh WHERE a IN (1,3,x,y); 863e3eff266Sdrh} {1 2 {} {} x 3 4 {} {} x} 864b6a9121bSdando_execsql_test join-15.106a { 865a1054dccSdan SELECT *, 'x' 866a1054dccSdan FROM t1 LEFT JOIN t2 867a1054dccSdan WHERE NOT ( 'x'='y' AND t2.y=1 ); 868a1054dccSdan} {1 2 {} {} x 3 4 {} {} x} 869b6a9121bSdando_execsql_test join-15.106b { 870b6a9121bSdan SELECT *, 'x' 871b6a9121bSdan FROM t1 LEFT JOIN t2 872b6a9121bSdan WHERE ~ ( 'x'='y' AND t2.y=1 ); 873b6a9121bSdan} {1 2 {} {} x 3 4 {} {} x} 8740493222fSdando_execsql_test join-15.107 { 8750493222fSdan SELECT *, 'x' 8760493222fSdan FROM t1 LEFT JOIN t2 8770493222fSdan WHERE t2.y IS NOT 'abc' 8780493222fSdan} {1 2 {} {} x 3 4 {} {} x} 8792c492061Sdrhdo_execsql_test join-15.110 { 8802c492061Sdrh DROP TABLE t1; 8812c492061Sdrh DROP TABLE t2; 8822c492061Sdrh CREATE TABLE t1(a INTEGER PRIMARY KEY, b INTEGER); 8832c492061Sdrh INSERT INTO t1(a,b) VALUES(1,0),(11,1),(12,1),(13,1),(121,12); 8842c492061Sdrh CREATE INDEX t1b ON t1(b); 8852c492061Sdrh CREATE TABLE t2(x INTEGER PRIMARY KEY); 8862c492061Sdrh INSERT INTO t2(x) VALUES(0),(1); 8872c492061Sdrh SELECT a1, a2, a3, a4, a5 8882c492061Sdrh FROM (SELECT a AS a1 FROM t1 WHERE b=0) 8892c492061Sdrh JOIN (SELECT x AS x1 FROM t2) 8902c492061Sdrh LEFT JOIN (SELECT a AS a2, b AS b2 FROM t1) 8912c492061Sdrh ON x1 IS TRUE AND b2=a1 8922c492061Sdrh JOIN (SELECT x AS x2 FROM t2) 8932c492061Sdrh ON x2<=CASE WHEN x1 THEN CASE WHEN a2 THEN 1 ELSE -1 END ELSE 0 END 8942c492061Sdrh LEFT JOIN (SELECT a AS a3, b AS b3 FROM t1) 8952c492061Sdrh ON x2 IS TRUE AND b3=a2 8962c492061Sdrh JOIN (SELECT x AS x3 FROM t2) 8972c492061Sdrh ON x3<=CASE WHEN x2 THEN CASE WHEN a3 THEN 1 ELSE -1 END ELSE 0 END 8982c492061Sdrh LEFT JOIN (SELECT a AS a4, b AS b4 FROM t1) 8992c492061Sdrh ON x3 IS TRUE AND b4=a3 9002c492061Sdrh JOIN (SELECT x AS x4 FROM t2) 9012c492061Sdrh ON x4<=CASE WHEN x3 THEN CASE WHEN a4 THEN 1 ELSE -1 END ELSE 0 END 9022c492061Sdrh LEFT JOIN (SELECT a AS a5, b AS b5 FROM t1) 9032c492061Sdrh ON x4 IS TRUE AND b5=a4 9042c492061Sdrh ORDER BY a1, a2, a3, a4, a5; 9052c492061Sdrh} {1 {} {} {} {} 1 11 {} {} {} 1 12 {} {} {} 1 12 121 {} {} 1 13 {} {} {}} 9062c492061Sdrh 907d5793672Sdrh# 2019-02-05 Ticket https://www.sqlite.org/src/tktview/5948e09b8c415bc45da5c 908d5793672Sdrh# Error in join due to the LEFT JOIN strength reduction optimization. 909d5793672Sdrh# 910d5793672Sdrhdo_execsql_test join-16.100 { 911d5793672Sdrh DROP TABLE IF EXISTS t1; 912d5793672Sdrh DROP TABLE IF EXISTS t2; 913d5793672Sdrh CREATE TABLE t1(a INT); 914d5793672Sdrh INSERT INTO t1(a) VALUES(1); 915d5793672Sdrh CREATE TABLE t2(b INT); 916d5793672Sdrh SELECT a, b 917d5793672Sdrh FROM t1 LEFT JOIN t2 ON 0 918d5793672Sdrh WHERE (b IS NOT NULL)=0; 919d5793672Sdrh} {1 {}} 920d5793672Sdrh 9219e9a67adSdrh# 2019-08-17 ticket https://sqlite.org/src/tktview/6710d2f7a13a299728ab 9229e9a67adSdrh# Ensure that constants that derive from the right-hand table of a LEFT JOIN 9239e9a67adSdrh# are never factored out, since they are not really constant. 9249e9a67adSdrh# 9259e9a67adSdrhdo_execsql_test join-17.100 { 9269e9a67adSdrh DROP TABLE IF EXISTS t1; 9279e9a67adSdrh CREATE TABLE t1(x); 9289e9a67adSdrh INSERT INTO t1(x) VALUES(0),(1); 9299e9a67adSdrh SELECT * FROM t1 LEFT JOIN (SELECT abs(1) AS y FROM t1) ON x WHERE NOT(y='a'); 9309e9a67adSdrh} {1 1 1 1} 9319e9a67adSdrhdo_execsql_test join-17.110 { 9329e9a67adSdrh SELECT * FROM t1 LEFT JOIN (SELECT abs(1)+2 AS y FROM t1) ON x 9339e9a67adSdrh WHERE NOT(y='a'); 9349e9a67adSdrh} {1 3 1 3} 9359e9a67adSdrh 936da03c1e6Sdan#------------------------------------------------------------------------- 937da03c1e6Sdanreset_db 938da03c1e6Sdando_execsql_test join-18.1 { 939da03c1e6Sdan CREATE TABLE t0(a); 940da03c1e6Sdan CREATE TABLE t1(b); 941da03c1e6Sdan CREATE VIEW v0 AS SELECT a FROM t1 LEFT JOIN t0; 942da03c1e6Sdan INSERT INTO t1 VALUES (1); 943da03c1e6Sdan} {} 944da03c1e6Sdan 945da03c1e6Sdando_execsql_test join-18.2 { 946da03c1e6Sdan SELECT * FROM v0 WHERE NOT(v0.a IS FALSE); 947da03c1e6Sdan} {{}} 948da03c1e6Sdan 949da03c1e6Sdando_execsql_test join-18.3 { 950da03c1e6Sdan SELECT * FROM t1 LEFT JOIN t0 WHERE NOT(a IS FALSE); 951da03c1e6Sdan} {1 {}} 952da03c1e6Sdan 953da03c1e6Sdando_execsql_test join-18.4 { 954da03c1e6Sdan SELECT NOT(v0.a IS FALSE) FROM v0 955da03c1e6Sdan} {1} 956da03c1e6Sdan 9570287c951Sdan#------------------------------------------------------------------------- 9580287c951Sdanreset_db 9590287c951Sdando_execsql_test join-19.0 { 9600287c951Sdan CREATE TABLE t1(a); 9610287c951Sdan CREATE TABLE t2(b); 9620287c951Sdan INSERT INTO t1(a) VALUES(0); 9630287c951Sdan CREATE VIEW v0(c) AS SELECT t2.b FROM t1 LEFT JOIN t2; 9640287c951Sdan} 9650287c951Sdan 9660287c951Sdando_execsql_test join-19.1 { 9670287c951Sdan SELECT * FROM v0 WHERE v0.c NOTNULL NOTNULL; 9680287c951Sdan} {{}} 9690287c951Sdan 9700287c951Sdando_execsql_test join-19.2 { 9710287c951Sdan SELECT * FROM t1 LEFT JOIN t2 9720287c951Sdan} {0 {}} 9730287c951Sdan 9740287c951Sdando_execsql_test join-19.3 { 9750287c951Sdan SELECT * FROM t1 LEFT JOIN t2 WHERE (b IS NOT NULL) IS NOT NULL; 9760287c951Sdan} {0 {}} 9770287c951Sdan 9780287c951Sdando_execsql_test join-19.4 { 9790287c951Sdan SELECT (b IS NOT NULL) IS NOT NULL FROM t1 LEFT JOIN t2 9800287c951Sdan} {1} 9810287c951Sdan 9820287c951Sdando_execsql_test join-19.5 { 9830287c951Sdan SELECT * FROM t1 LEFT JOIN t2 WHERE 9840287c951Sdan (b IS NOT NULL AND b IS NOT NULL) IS NOT NULL; 9850287c951Sdan} {0 {}} 9860287c951Sdan 987db535390Sdrh# 2019-11-02 ticket 623eff57e76d45f6 988db535390Sdrh# The optimization of exclusing the WHERE expression of a partial index 989db535390Sdrh# from the WHERE clause of the query if the index is used does not work 990db535390Sdrh# of the table of the index is the right-hand table of a LEFT JOIN. 991db535390Sdrh# 992db535390Sdrhdb close 993db535390Sdrhsqlite3 db :memory: 994db535390Sdrhdo_execsql_test join-20.1 { 995db535390Sdrh CREATE TABLE t1(c1); 996db535390Sdrh CREATE TABLE t0(c0); 997db535390Sdrh INSERT INTO t0(c0) VALUES (0); 998db535390Sdrh SELECT * FROM t0 LEFT JOIN t1 WHERE NULL IN (c1); 999db535390Sdrh} {} 1000db535390Sdrhdo_execsql_test join-20.2 { 1001db535390Sdrh CREATE INDEX t1x ON t1(0) WHERE NULL IN (c1); 1002db535390Sdrh SELECT * FROM t0 LEFT JOIN t1 WHERE NULL IN (c1); 1003db535390Sdrh} {} 1004db535390Sdrh 1005ca7a26b5Sdrh# 2019-11-30 ticket 7f39060a24b47353 1006ca7a26b5Sdrh# Do not allow a WHERE clause term to qualify a partial index on the 1007ca7a26b5Sdrh# right table of a LEFT JOIN. 1008ca7a26b5Sdrh# 1009ca7a26b5Sdrhdo_execsql_test join-21.10 { 1010ca7a26b5Sdrh DROP TABLE t0; 1011ca7a26b5Sdrh DROP TABLE t1; 1012ca7a26b5Sdrh CREATE TABLE t0(aa); 1013ca7a26b5Sdrh CREATE TABLE t1(bb); 1014ca7a26b5Sdrh INSERT INTO t0(aa) VALUES (1); 1015ca7a26b5Sdrh INSERT INTO t1(bb) VALUES (1); 1016ca7a26b5Sdrh SELECT 11, * FROM t1 LEFT JOIN t0 WHERE aa ISNULL; 1017ca7a26b5Sdrh SELECT 12, * FROM t1 LEFT JOIN t0 WHERE +aa ISNULL; 1018ca7a26b5Sdrh SELECT 13, * FROM t1 LEFT JOIN t0 ON aa ISNULL; 1019ca7a26b5Sdrh SELECT 14, * FROM t1 LEFT JOIN t0 ON +aa ISNULL; 1020ca7a26b5Sdrh CREATE INDEX i0 ON t0(aa) WHERE aa ISNULL; 1021ca7a26b5Sdrh SELECT 21, * FROM t1 LEFT JOIN t0 WHERE aa ISNULL; 1022ca7a26b5Sdrh SELECT 22, * FROM t1 LEFT JOIN t0 WHERE +aa ISNULL; 1023ca7a26b5Sdrh SELECT 23, * FROM t1 LEFT JOIN t0 ON aa ISNULL; 1024ca7a26b5Sdrh SELECT 24, * FROM t1 LEFT JOIN t0 ON +aa ISNULL; 1025ca7a26b5Sdrh} {13 1 {} 14 1 {} 23 1 {} 24 1 {}} 1026ca7a26b5Sdrh 1027396afe6fSdrh# 2019-12-18 problem with a LEFT JOIN where the RHS is a view. 1028396afe6fSdrh# Detected by Yongheng and Rui. 1029396afe6fSdrh# Follows from the optimization attempt of check-in 41c27bc0ff1d3135 1030396afe6fSdrh# on 2017-04-18 1031396afe6fSdrh# 1032396afe6fSdrhreset_db 1033396afe6fSdrhdo_execsql_test join-22.10 { 1034396afe6fSdrh CREATE TABLE t0(a, b); 1035396afe6fSdrh CREATE INDEX t0a ON t0(a); 1036396afe6fSdrh INSERT INTO t0 VALUES(10,10),(10,11),(10,12); 1037396afe6fSdrh SELECT DISTINCT c FROM t0 LEFT JOIN (SELECT a+1 AS c FROM t0) ORDER BY c ; 1038396afe6fSdrh} {11} 1039396afe6fSdrh 10406e827fa2Sdrh# 2019-12-22 ticket 7929c1efb2d67e98 10416e827fa2Sdrh# 10426e827fa2Sdrhreset_db 10438c812f98Sdanifcapable vtab { 10446e827fa2Sdrhdo_execsql_test join-23.10 { 10456e827fa2Sdrh CREATE TABLE t0(c0); 10466e827fa2Sdrh INSERT INTO t0(c0) VALUES(123); 10476e827fa2Sdrh CREATE VIEW v0(c0) AS SELECT 0 GROUP BY 1; 10486e827fa2Sdrh SELECT t0.c0, v0.c0, vt0.name 10496e827fa2Sdrh FROM v0, t0 LEFT JOIN pragma_table_info('t0') AS vt0 10506e827fa2Sdrh ON vt0.name LIKE 'c0' 10516e827fa2Sdrh WHERE v0.c0 == 0; 10526e827fa2Sdrh} {123 0 c0} 10538c812f98Sdan} 10546e827fa2Sdrh 105551f2b171Sdan#------------------------------------------------------------------------- 105651f2b171Sdanreset_db 105751f2b171Sdando_execsql_test join-24.1 { 105851f2b171Sdan CREATE TABLE t1(a PRIMARY KEY, x); 105951f2b171Sdan CREATE TABLE t2(b INT); 106051f2b171Sdan CREATE INDEX t1aa ON t1(a, a); 106151f2b171Sdan 106251f2b171Sdan INSERT INTO t1 VALUES('abc', 'def'); 106351f2b171Sdan INSERT INTO t2 VALUES(1); 106451f2b171Sdan} 106551f2b171Sdan 106651f2b171Sdando_execsql_test join-24.2 { 106751f2b171Sdan SELECT * FROM t2 JOIN t1 WHERE a='abc' AND x='def'; 106851f2b171Sdan} {1 abc def} 106951f2b171Sdando_execsql_test join-24.3 { 107051f2b171Sdan SELECT * FROM t2 JOIN t1 WHERE a='abc' AND x='abc'; 107151f2b171Sdan} {} 107251f2b171Sdan 107351f2b171Sdando_execsql_test join-24.2 { 107451f2b171Sdan SELECT * FROM t2 LEFT JOIN t1 ON a=0 WHERE (x='x' OR x IS NULL); 107551f2b171Sdan} {1 {} {}} 10766e827fa2Sdrh 1077af371153Sdrh# 2020-09-30 ticket 66e4b0e271c47145 1078af371153Sdrh# The query flattener inserts an "expr AND expr" expression as a substitution 1079af371153Sdrh# for the column of a view where that view column is part of an ON expression 1080af371153Sdrh# of a LEFT JOIN. 1081af371153Sdrh# 1082af371153Sdrhreset_db 1083af371153Sdrhdo_execsql_test join-25.1 { 1084af371153Sdrh CREATE TABLE t0(c0 INT); 1085af371153Sdrh CREATE VIEW v0 AS SELECT (NULL AND 5) as c0 FROM t0; 1086af371153Sdrh INSERT INTO t0(c0) VALUES (NULL); 1087af371153Sdrh SELECT count(*) FROM v0 LEFT JOIN t0 ON v0.c0; 1088af371153Sdrh} {1} 108951f2b171Sdan 1090825a6bffSdrh# 2022-04-21 Parser issue detected by dbsqlfuzz 1091825a6bffSdrh# 1092825a6bffSdrhreset_db 1093825a6bffSdrhdo_catchsql_test join-26.1 { 1094825a6bffSdrh CREATE TABLE t4(a,b); 1095825a6bffSdrh CREATE TABLE t5(a,c); 1096825a6bffSdrh CREATE TABLE t6(a,d); 1097825a6bffSdrh SELECT * FROM t5 JOIN ((t4 JOIN (t5 JOIN t6)) t7); 1098825a6bffSdrh} {/1 {.*}/} 1099af371153Sdrh 1100a341bae9Sdrh# 2022-06-09 Invalid subquery flattening caused by 1101a341bae9Sdrh# check-in 3f45007d544e5f78 and detected by dbsqlfuzz 1102a341bae9Sdrh# 1103a341bae9Sdrhreset_db 1104a341bae9Sdrhdo_execsql_test join-27.1 { 1105a341bae9Sdrh CREATE TABLE t1(a INT,b INT,c INT); INSERT INTO t1 VALUES(NULL,NULL,NULL); 1106a341bae9Sdrh CREATE TABLE t2(d INT,e INT); INSERT INTO t2 VALUES(NULL,NULL); 1107a341bae9Sdrh CREATE INDEX x2 ON t1(c,b); 1108a341bae9Sdrh CREATE TABLE t3(x INT); INSERT INTO t3 VALUES(NULL); 1109a341bae9Sdrh} 1110a341bae9Sdrhdo_execsql_test join-27.2 { 1111a341bae9Sdrh WITH t99(b) AS MATERIALIZED ( 1112a341bae9Sdrh SELECT b FROM t2 LEFT JOIN t1 ON c IN (SELECT x FROM t3) 1113a341bae9Sdrh ) 1114a341bae9Sdrh SELECT 5 FROM t2 JOIN t99 ON b IN (1,2,3); 1115a341bae9Sdrh} {} 1116a341bae9Sdrhdo_execsql_test join-27.3 { 1117a341bae9Sdrh WITH t99(b) AS NOT MATERIALIZED ( 1118a341bae9Sdrh SELECT b FROM t2 LEFT JOIN t1 ON c IN (SELECT x FROM t3) 1119a341bae9Sdrh ) 1120a341bae9Sdrh SELECT 5 FROM t2 JOIN t99 ON b IN (1,2,3); 1121a341bae9Sdrh} {} 1122a341bae9Sdrhdo_execsql_test join-27.4 { 1123a341bae9Sdrh WITH t99(b) AS (SELECT b FROM t2 LEFT JOIN t1 ON c IN (SELECT x FROM t3)) 1124a341bae9Sdrh SELECT 5 FROM t2 JOIN t99 ON b IN (1,2,3); 1125a341bae9Sdrh} {} 1126a341bae9Sdrhdo_execsql_test join-27.5 { 1127a341bae9Sdrh SELECT 5 1128a341bae9Sdrh FROM t2 JOIN ( 1129a341bae9Sdrh SELECT b FROM t2 LEFT JOIN t1 ON c IN (SELECT x FROM t3) 1130a341bae9Sdrh ) AS t99 ON b IN (1,2,3); 1131a341bae9Sdrh} {} 1132a341bae9Sdrh 1133*c9099d2dSstephandb null NULL 1134*c9099d2dSstephando_execsql_test join-27.6 { 1135*c9099d2dSstephan INSERT INTO t1 VALUES(3,4,NULL); 1136*c9099d2dSstephan INSERT INTO t2 VALUES(1,2); 1137*c9099d2dSstephan WITH t99(b) AS ( 1138*c9099d2dSstephan SELECT coalesce(b,3) FROM t2 AS x LEFT JOIN t1 ON c IN (SELECT x FROM t3) 1139*c9099d2dSstephan ) 1140*c9099d2dSstephan SELECT d, e, b FROM t2 JOIN t99 ON b IN (1,2,3) ORDER BY +d; 1141*c9099d2dSstephan} {NULL NULL 3 NULL NULL 3 1 2 3 1 2 3} 1142*c9099d2dSstephando_execsql_test join-27.7 { 1143*c9099d2dSstephan SELECT d, e, b2 1144*c9099d2dSstephan FROM t2 1145*c9099d2dSstephan JOIN (SELECT coalesce(b,3) AS b2 FROM t2 AS x LEFT JOIN t1 1146*c9099d2dSstephan ON c IN (SELECT x FROM t3)) AS t99 1147*c9099d2dSstephan ON b2 IN (1,2,3) ORDER BY +d; 1148*c9099d2dSstephan} {NULL NULL 3 NULL NULL 3 1 2 3 1 2 3} 1149*c9099d2dSstephan 1150*c9099d2dSstephando_execsql_test join-27.8 { 1151*c9099d2dSstephan DELETE FROM t1; 1152*c9099d2dSstephan DELETE FROM t2 WHERE d IS NOT NULL; 1153*c9099d2dSstephan DELETE FROM t3; 1154*c9099d2dSstephan SELECT * FROM t2 JOIN (SELECT b FROM t2 LEFT JOIN t1 1155*c9099d2dSstephan ON c IN (SELECT x FROM t3)) AS t99 ON b IN (1,2,3); 1156*c9099d2dSstephan} {} 1157*c9099d2dSstephan 1158*c9099d2dSstephando_execsql_test join-27.9 { 1159*c9099d2dSstephan DELETE FROM t1; 1160*c9099d2dSstephan DELETE FROM t2; 1161*c9099d2dSstephan DELETE FROM t3; 1162*c9099d2dSstephan INSERT INTO t1 VALUES(4,3,5); 1163*c9099d2dSstephan INSERT INTO t2 VALUES(1,2); 1164*c9099d2dSstephan INSERT INTO t3 VALUES(5); 1165*c9099d2dSstephan SELECT * FROM t2 JOIN (SELECT b FROM t2 LEFT JOIN t1 1166*c9099d2dSstephan ON c IN (SELECT x FROM t3)) AS t99 ON b IS NULL; 1167*c9099d2dSstephan} {} 1168*c9099d2dSstephando_execsql_test join-27.10 { 1169*c9099d2dSstephan WITH t99(b) AS ( 1170*c9099d2dSstephan SELECT b FROM t2 AS x LEFT JOIN t1 ON c IN (SELECT x FROM t3) 1171*c9099d2dSstephan ) 1172*c9099d2dSstephan SELECT d, e, b FROM t2 JOIN t99 ON b IS NULL; 1173*c9099d2dSstephan} {} 1174*c9099d2dSstephan 1175*c9099d2dSstephan 1176*c9099d2dSstephan# 2022-09-19 https://sqlite.org/forum/forumpost/96b9e5709cf47cda 1177*c9099d2dSstephan# Performance regression relative to version 3.38.0 that resulted from 1178*c9099d2dSstephan# a new query flattener restriction that was added to fixes the join-27.* 1179*c9099d2dSstephan# tests above. The restriction needed to be removed and the join-27.* 1180*c9099d2dSstephan# problem fixed another way. 1181*c9099d2dSstephan# 1182*c9099d2dSstephanreset_db 1183*c9099d2dSstephando_execsql_test join-28.1 { 1184*c9099d2dSstephan CREATE TABLE t1(a INTEGER PRIMARY KEY, b INT, c INT); 1185*c9099d2dSstephan CREATE TABLE t2(d INTEGER PRIMARY KEY, e INT); 1186*c9099d2dSstephan CREATE VIEW t3(a,b,c,d,e) AS SELECT * FROM t1 LEFT JOIN t2 ON d=c; 1187*c9099d2dSstephan CREATE TABLE t4(x INT, y INT); 1188*c9099d2dSstephan INSERT INTO t1 VALUES(1,2,3); 1189*c9099d2dSstephan INSERT INTO t2 VALUES(1,5); 1190*c9099d2dSstephan INSERT INTO t4 VALUES(1,4); 1191*c9099d2dSstephan SELECT a, b, y FROM t4 JOIN t3 ON a=x; 1192*c9099d2dSstephan} {1 2 4} 1193*c9099d2dSstephando_eqp_test join-28.2 { 1194*c9099d2dSstephan SELECT a, b, y FROM t4 JOIN t3 ON a=x; 1195*c9099d2dSstephan} { 1196*c9099d2dSstephan QUERY PLAN 1197*c9099d2dSstephan |--SCAN t4 1198*c9099d2dSstephan `--SEARCH t1 USING INTEGER PRIMARY KEY (rowid=?) 1199*c9099d2dSstephan} 1200*c9099d2dSstephan# ^^^^^^^ Without the fix (if the query flattening optimization does not 1201*c9099d2dSstephan# run) the query plan above would look like this: 1202*c9099d2dSstephan# 1203*c9099d2dSstephan# QUERY PLAN 1204*c9099d2dSstephan# |--MATERIALIZE t3 1205*c9099d2dSstephan# | |--SCAN t1 1206*c9099d2dSstephan# | `--SEARCH t2 USING INTEGER PRIMARY KEY (rowid=?) LEFT-JOIN 1207*c9099d2dSstephan# |--SCAN t4 1208*c9099d2dSstephan# `--SEARCH t3 USING AUTOMATIC COVERING INDEX (a=?) 1209a341bae9Sdrh 1210af371153Sdrhfinish_test 1211