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