1570b935cSdrh# 2006 January 31 2570b935cSdrh# 3570b935cSdrh# The author disclaims copyright to this source code. In place of 4570b935cSdrh# a legal notice, here is a blessing: 5570b935cSdrh# 6570b935cSdrh# May you do good and not evil. 7570b935cSdrh# May you find forgiveness for yourself and forgive others. 8570b935cSdrh# May you share freely, never taking more than you give. 9570b935cSdrh# 10570b935cSdrh#*********************************************************************** 11570b935cSdrh# This file implements regression tests for SQLite library. The 12570b935cSdrh# focus of this file is testing the join reordering optimization 13570b935cSdrh# in cases that include a LEFT JOIN. 14570b935cSdrh# 15dafc0ce8Sdrh# $Id: where3.test,v 1.4 2008/04/17 19:14:02 drh Exp $ 16570b935cSdrh 17570b935cSdrhset testdir [file dirname $argv0] 18570b935cSdrhsource $testdir/tester.tcl 19570b935cSdrh 20570b935cSdrh# The following is from ticket #1652. 21570b935cSdrh# 22570b935cSdrh# A comma join then a left outer join: A,B left join C. 23570b935cSdrh# Arrange indices so that the B table is chosen to go first. 24570b935cSdrh# Also put an index on C, but make sure that A is chosen before C. 25570b935cSdrh# 26570b935cSdrhdo_test where3-1.1 { 27570b935cSdrh execsql { 28570b935cSdrh CREATE TABLE t1(a, b); 29570b935cSdrh CREATE TABLE t2(p, q); 30570b935cSdrh CREATE TABLE t3(x, y); 31570b935cSdrh 32570b935cSdrh INSERT INTO t1 VALUES(111,'one'); 33570b935cSdrh INSERT INTO t1 VALUES(222,'two'); 34570b935cSdrh INSERT INTO t1 VALUES(333,'three'); 35570b935cSdrh 36570b935cSdrh INSERT INTO t2 VALUES(1,111); 37570b935cSdrh INSERT INTO t2 VALUES(2,222); 38570b935cSdrh INSERT INTO t2 VALUES(4,444); 39570b935cSdrh CREATE INDEX t2i1 ON t2(p); 40570b935cSdrh 41570b935cSdrh INSERT INTO t3 VALUES(999,'nine'); 42570b935cSdrh CREATE INDEX t3i1 ON t3(x); 43570b935cSdrh 44570b935cSdrh SELECT * FROM t1, t2 LEFT JOIN t3 ON q=x WHERE p=2 AND a=q; 45570b935cSdrh } 46570b935cSdrh} {222 two 2 222 {} {}} 47570b935cSdrh 48c4974414Sdanifcapable explain&&!cursorhints { 49dafc0ce8Sdrh do_test where3-1.1.1 { 50dafc0ce8Sdrh explain_no_trace {SELECT * FROM t1, t2 LEFT JOIN t3 ON q=x 51dafc0ce8Sdrh WHERE p=2 AND a=q} 52dafc0ce8Sdrh } [explain_no_trace {SELECT * FROM t1, t2 LEFT JOIN t3 ON x=q 53dafc0ce8Sdrh WHERE p=2 AND a=q}] 54dafc0ce8Sdrh} 55dafc0ce8Sdrh 56df26fd5eSdrh# Ticket #1830 57df26fd5eSdrh# 58df26fd5eSdrh# This is similar to the above but with the LEFT JOIN on the 59df26fd5eSdrh# other side. 60df26fd5eSdrh# 61df26fd5eSdrhdo_test where3-1.2 { 62df26fd5eSdrh execsql { 63df26fd5eSdrh CREATE TABLE parent1(parent1key, child1key, Child2key, child3key); 64df26fd5eSdrh CREATE TABLE child1 ( child1key NVARCHAR, value NVARCHAR ); 65df26fd5eSdrh CREATE UNIQUE INDEX PKIDXChild1 ON child1 ( child1key ); 66df26fd5eSdrh CREATE TABLE child2 ( child2key NVARCHAR, value NVARCHAR ); 67df26fd5eSdrh 68df26fd5eSdrh INSERT INTO parent1(parent1key,child1key,child2key) 69df26fd5eSdrh VALUES ( 1, 'C1.1', 'C2.1' ); 70df26fd5eSdrh INSERT INTO child1 ( child1key, value ) VALUES ( 'C1.1', 'Value for C1.1' ); 71df26fd5eSdrh INSERT INTO child2 ( child2key, value ) VALUES ( 'C2.1', 'Value for C2.1' ); 72df26fd5eSdrh 73df26fd5eSdrh INSERT INTO parent1 ( parent1key, child1key, child2key ) 74df26fd5eSdrh VALUES ( 2, 'C1.2', 'C2.2' ); 75df26fd5eSdrh INSERT INTO child2 ( child2key, value ) VALUES ( 'C2.2', 'Value for C2.2' ); 76df26fd5eSdrh 77df26fd5eSdrh INSERT INTO parent1 ( parent1key, child1key, child2key ) 78df26fd5eSdrh VALUES ( 3, 'C1.3', 'C2.3' ); 79df26fd5eSdrh INSERT INTO child1 ( child1key, value ) VALUES ( 'C1.3', 'Value for C1.3' ); 80df26fd5eSdrh INSERT INTO child2 ( child2key, value ) VALUES ( 'C2.3', 'Value for C2.3' ); 81df26fd5eSdrh 82df26fd5eSdrh SELECT parent1.parent1key, child1.value, child2.value 83df26fd5eSdrh FROM parent1 84df26fd5eSdrh LEFT OUTER JOIN child1 ON child1.child1key = parent1.child1key 85df26fd5eSdrh INNER JOIN child2 ON child2.child2key = parent1.child2key; 86df26fd5eSdrh } 87df26fd5eSdrh} {1 {Value for C1.1} {Value for C2.1} 2 {} {Value for C2.2} 3 {Value for C1.3} {Value for C2.3}} 88570b935cSdrh 89c4974414Sdanifcapable explain&&!cursorhints { 90dafc0ce8Sdrh do_test where3-1.2.1 { 91dafc0ce8Sdrh explain_no_trace { 92dafc0ce8Sdrh SELECT parent1.parent1key, child1.value, child2.value 93dafc0ce8Sdrh FROM parent1 94dafc0ce8Sdrh LEFT OUTER JOIN child1 ON child1.child1key = parent1.child1key 95dafc0ce8Sdrh INNER JOIN child2 ON child2.child2key = parent1.child2key; 96dafc0ce8Sdrh } 97dafc0ce8Sdrh } [explain_no_trace { 98dafc0ce8Sdrh SELECT parent1.parent1key, child1.value, child2.value 99dafc0ce8Sdrh FROM parent1 100dafc0ce8Sdrh LEFT OUTER JOIN child1 ON parent1.child1key = child1.child1key 101dafc0ce8Sdrh INNER JOIN child2 ON child2.child2key = parent1.child2key; 102dafc0ce8Sdrh }] 103dafc0ce8Sdrh} 104dafc0ce8Sdrh 10561dfc31dSdrh# This procedure executes the SQL. Then it appends 1067c171098Sdrh# the names of the table and index used 10761dfc31dSdrh# 10861dfc31dSdrhproc queryplan {sql} { 10961dfc31dSdrh set ::sqlite_sort_count 0 11061dfc31dSdrh set data [execsql $sql] 1117c171098Sdrh set eqp [execsql "EXPLAIN QUERY PLAN $sql"] 1127c171098Sdrh # puts eqp=$eqp 1137c171098Sdrh foreach {a b c x} $eqp { 114*8210233cSdrh if {[regexp {SCAN CONSTANT} $x]} { 115*8210233cSdrh # noop 116*8210233cSdrh } elseif {[regexp {(SCAN|SEARCH) (\w+ AS )?(\w+) USING.* INDEX (\w+)\y} \ 117*8210233cSdrh $x all ss as tab idx]} { 1187c171098Sdrh lappend data $tab $idx 119*8210233cSdrh } elseif {[regexp {(SCAN|SEARCH) (\w+ AS )?(\w+)\y} $x all ss as tab]} { 1207c171098Sdrh lappend data $tab * 1217c171098Sdrh } 1227c171098Sdrh } 1237c171098Sdrh return $data 12461dfc31dSdrh} 12561dfc31dSdrh 12661dfc31dSdrh 12761dfc31dSdrh# If you have a from clause of the form: A B C left join D 12861dfc31dSdrh# then make sure the query optimizer is able to reorder the 12961dfc31dSdrh# A B C part anyway it wants. 13061dfc31dSdrh# 13161dfc31dSdrh# Following the fix to ticket #1652, there was a time when 13261dfc31dSdrh# the C table would not reorder. So the following reorderings 13361dfc31dSdrh# were possible: 13461dfc31dSdrh# 13561dfc31dSdrh# A B C left join D 13661dfc31dSdrh# B A C left join D 13761dfc31dSdrh# 13861dfc31dSdrh# But these reorders were not allowed 13961dfc31dSdrh# 14061dfc31dSdrh# C A B left join D 14161dfc31dSdrh# A C B left join D 14261dfc31dSdrh# C B A left join D 14361dfc31dSdrh# B C A left join D 14461dfc31dSdrh# 14561dfc31dSdrh# The following tests are here to verify that the latter four 14661dfc31dSdrh# reorderings are allowed again. 14761dfc31dSdrh# 14861dfc31dSdrhdo_test where3-2.1 { 14961dfc31dSdrh execsql { 15061dfc31dSdrh CREATE TABLE tA(apk integer primary key, ax); 15161dfc31dSdrh CREATE TABLE tB(bpk integer primary key, bx); 15261dfc31dSdrh CREATE TABLE tC(cpk integer primary key, cx); 15361dfc31dSdrh CREATE TABLE tD(dpk integer primary key, dx); 15461dfc31dSdrh } 15561dfc31dSdrh queryplan { 15661dfc31dSdrh SELECT * FROM tA, tB, tC LEFT JOIN tD ON dpk=cx 15761dfc31dSdrh WHERE cpk=bx AND bpk=ax 15861dfc31dSdrh } 1597c171098Sdrh} {tA * tB * tC * tD *} 160dafc0ce8Sdrhdo_test where3-2.1.1 { 161dafc0ce8Sdrh queryplan { 162dafc0ce8Sdrh SELECT * FROM tA, tB, tC LEFT JOIN tD ON cx=dpk 163dafc0ce8Sdrh WHERE cpk=bx AND bpk=ax 164dafc0ce8Sdrh } 1657c171098Sdrh} {tA * tB * tC * tD *} 166dafc0ce8Sdrhdo_test where3-2.1.2 { 167dafc0ce8Sdrh queryplan { 168dafc0ce8Sdrh SELECT * FROM tA, tB, tC LEFT JOIN tD ON cx=dpk 169dafc0ce8Sdrh WHERE bx=cpk AND bpk=ax 170dafc0ce8Sdrh } 1717c171098Sdrh} {tA * tB * tC * tD *} 172dafc0ce8Sdrhdo_test where3-2.1.3 { 173dafc0ce8Sdrh queryplan { 174dafc0ce8Sdrh SELECT * FROM tA, tB, tC LEFT JOIN tD ON cx=dpk 175dafc0ce8Sdrh WHERE bx=cpk AND ax=bpk 176dafc0ce8Sdrh } 1777c171098Sdrh} {tA * tB * tC * tD *} 178dafc0ce8Sdrhdo_test where3-2.1.4 { 179dafc0ce8Sdrh queryplan { 180dafc0ce8Sdrh SELECT * FROM tA, tB, tC LEFT JOIN tD ON dpk=cx 181dafc0ce8Sdrh WHERE bx=cpk AND ax=bpk 182dafc0ce8Sdrh } 1837c171098Sdrh} {tA * tB * tC * tD *} 184dafc0ce8Sdrhdo_test where3-2.1.5 { 185dafc0ce8Sdrh queryplan { 186dafc0ce8Sdrh SELECT * FROM tA, tB, tC LEFT JOIN tD ON dpk=cx 187dafc0ce8Sdrh WHERE cpk=bx AND ax=bpk 188dafc0ce8Sdrh } 1897c171098Sdrh} {tA * tB * tC * tD *} 19061dfc31dSdrhdo_test where3-2.2 { 19161dfc31dSdrh queryplan { 19261dfc31dSdrh SELECT * FROM tA, tB, tC LEFT JOIN tD ON dpk=cx 19361dfc31dSdrh WHERE cpk=bx AND apk=bx 19461dfc31dSdrh } 195e353ee38Sdrh} {tB * tA * tC * tD *} 19661dfc31dSdrhdo_test where3-2.3 { 19761dfc31dSdrh queryplan { 19861dfc31dSdrh SELECT * FROM tA, tB, tC LEFT JOIN tD ON dpk=cx 19961dfc31dSdrh WHERE cpk=bx AND apk=bx 20061dfc31dSdrh } 201e353ee38Sdrh} {tB * tA * tC * tD *} 20261dfc31dSdrhdo_test where3-2.4 { 20361dfc31dSdrh queryplan { 20461dfc31dSdrh SELECT * FROM tA, tB, tC LEFT JOIN tD ON dpk=cx 20561dfc31dSdrh WHERE apk=cx AND bpk=ax 20661dfc31dSdrh } 207e353ee38Sdrh} {tC * tA * tB * tD *} 20861dfc31dSdrhdo_test where3-2.5 { 20961dfc31dSdrh queryplan { 21061dfc31dSdrh SELECT * FROM tA, tB, tC LEFT JOIN tD ON dpk=cx 21161dfc31dSdrh WHERE cpk=ax AND bpk=cx 21261dfc31dSdrh } 213e353ee38Sdrh} {tA * tC * tB * tD *} 214ed754ce2Sdrhdo_test where3-2.6 { 21561dfc31dSdrh queryplan { 21661dfc31dSdrh SELECT * FROM tA, tB, tC LEFT JOIN tD ON dpk=cx 21761dfc31dSdrh WHERE bpk=cx AND apk=bx 21861dfc31dSdrh } 219e353ee38Sdrh} {tC * tB * tA * tD *} 220ed754ce2Sdrhdo_test where3-2.7 { 22161dfc31dSdrh queryplan { 22261dfc31dSdrh SELECT * FROM tA, tB, tC LEFT JOIN tD ON dpk=cx 22361dfc31dSdrh WHERE cpk=bx AND apk=cx 22461dfc31dSdrh } 225e353ee38Sdrh} {tB * tC * tA * tD *} 22661dfc31dSdrh 2275e377d90Sdrh# Ticket [13f033c865f878953] 2285e377d90Sdrh# If the outer loop must be a full table scan, do not let ANALYZE trick 2295e377d90Sdrh# the planner into use a table for the outer loop that might be indexable 2305e377d90Sdrh# if held until an inner loop. 2315e377d90Sdrh# 23247eb16d4Sdando_execsql_test where3-3.0 { 2335e377d90Sdrh CREATE TABLE t301(a INTEGER PRIMARY KEY,b,c); 2345e377d90Sdrh CREATE INDEX t301c ON t301(c); 2355e377d90Sdrh INSERT INTO t301 VALUES(1,2,3); 236aa9933c1Sdan INSERT INTO t301 VALUES(2,2,3); 2375e377d90Sdrh CREATE TABLE t302(x, y); 238f6cf1ffbSdrh INSERT INTO t302 VALUES(4,5); 2395e377d90Sdrh ANALYZE; 2405e377d90Sdrh} 241cdf88760Sdrhdo_eqp_test where3-3.0a { 242cdf88760Sdrh SELECT * FROM t302, t301 WHERE t302.x=5 AND t301.a=t302.y; 243cdf88760Sdrh} { 244cdf88760Sdrh QUERY PLAN 245*8210233cSdrh |--SCAN t302 246*8210233cSdrh `--SEARCH t301 USING INTEGER PRIMARY KEY (rowid=?) 247cdf88760Sdrh} 248cdf88760Sdrhdo_eqp_test where3-3.1 { 2495e377d90Sdrh SELECT * FROM t301, t302 WHERE t302.x=5 AND t301.a=t302.y; 25047eb16d4Sdan} { 251cdf88760Sdrh QUERY PLAN 252*8210233cSdrh |--SCAN t302 253*8210233cSdrh `--SEARCH t301 USING INTEGER PRIMARY KEY (rowid=?) 2545e377d90Sdrh} 255d0aa2f3aSdrhdo_execsql_test where3-3.2 { 256d0aa2f3aSdrh SELECT * FROM t301 WHERE c=3 AND a IS NULL; 257d0aa2f3aSdrh} {} 258d0aa2f3aSdrhdo_execsql_test where3-3.3 { 259d0aa2f3aSdrh SELECT * FROM t301 WHERE c=3 AND a IS NOT NULL; 260aa9933c1Sdan} {1 2 3 2 2 3} 26161dfc31dSdrh 2624fe425adSdrhif 0 { # Query planner no longer does this 263aa0ba434Sdrh# Verify that when there are multiple tables in a join which must be 264aa0ba434Sdrh# full table scans that the query planner attempts put the table with 265aa0ba434Sdrh# the fewest number of output rows as the outer loop. 266aa0ba434Sdrh# 26747eb16d4Sdando_execsql_test where3-4.0 { 268aa0ba434Sdrh CREATE TABLE t400(a INTEGER PRIMARY KEY, b, c); 269aa0ba434Sdrh CREATE TABLE t401(p INTEGER PRIMARY KEY, q, r); 270aa0ba434Sdrh CREATE TABLE t402(x INTEGER PRIMARY KEY, y, z); 271aa0ba434Sdrh EXPLAIN QUERY PLAN 272aa0ba434Sdrh SELECT * FROM t400, t401, t402 WHERE t402.z GLOB 'abc*'; 27347eb16d4Sdan} { 274*8210233cSdrh 0 0 2 {SCAN t402} 275*8210233cSdrh 0 1 0 {SCAN t400} 276*8210233cSdrh 0 2 1 {SCAN t401} 277aa0ba434Sdrh} 27847eb16d4Sdando_execsql_test where3-4.1 { 279aa0ba434Sdrh EXPLAIN QUERY PLAN 280aa0ba434Sdrh SELECT * FROM t400, t401, t402 WHERE t401.r GLOB 'abc*'; 28147eb16d4Sdan} { 282*8210233cSdrh 0 0 1 {SCAN t401} 283*8210233cSdrh 0 1 0 {SCAN t400} 284*8210233cSdrh 0 2 2 {SCAN t402} 285aa0ba434Sdrh} 28647eb16d4Sdando_execsql_test where3-4.2 { 287aa0ba434Sdrh EXPLAIN QUERY PLAN 288aa0ba434Sdrh SELECT * FROM t400, t401, t402 WHERE t400.c GLOB 'abc*'; 28947eb16d4Sdan} { 290*8210233cSdrh 0 0 0 {SCAN t400} 291*8210233cSdrh 0 1 1 {SCAN t401} 292*8210233cSdrh 0 2 2 {SCAN t402} 293aa0ba434Sdrh} 2944fe425adSdrh} ;# endif 295aa0ba434Sdrh 296547caad4Sdrh# Verify that a performance regression encountered by firefox 297547caad4Sdrh# has been fixed. 298547caad4Sdrh# 29947eb16d4Sdando_execsql_test where3-5.0 { 300547caad4Sdrh CREATE TABLE aaa (id INTEGER PRIMARY KEY, type INTEGER, 301547caad4Sdrh fk INTEGER DEFAULT NULL, parent INTEGER, 302547caad4Sdrh position INTEGER, title LONGVARCHAR, 303547caad4Sdrh keyword_id INTEGER, folder_type TEXT, 304547caad4Sdrh dateAdded INTEGER, lastModified INTEGER); 305547caad4Sdrh CREATE INDEX aaa_111 ON aaa (fk, type); 306547caad4Sdrh CREATE INDEX aaa_222 ON aaa (parent, position); 307547caad4Sdrh CREATE INDEX aaa_333 ON aaa (fk, lastModified); 308547caad4Sdrh CREATE TABLE bbb (id INTEGER PRIMARY KEY, type INTEGER, 309547caad4Sdrh fk INTEGER DEFAULT NULL, parent INTEGER, 310547caad4Sdrh position INTEGER, title LONGVARCHAR, 311547caad4Sdrh keyword_id INTEGER, folder_type TEXT, 312547caad4Sdrh dateAdded INTEGER, lastModified INTEGER); 313547caad4Sdrh CREATE INDEX bbb_111 ON bbb (fk, type); 314547caad4Sdrh CREATE INDEX bbb_222 ON bbb (parent, position); 315547caad4Sdrh CREATE INDEX bbb_333 ON bbb (fk, lastModified); 316cdf88760Sdrh} 317cdf88760Sdrhdo_eqp_test where3-5.0a { 318547caad4Sdrh SELECT bbb.title AS tag_title 319547caad4Sdrh FROM aaa JOIN bbb ON bbb.id = aaa.parent 320547caad4Sdrh WHERE aaa.fk = 'constant' 321547caad4Sdrh AND LENGTH(bbb.title) > 0 322547caad4Sdrh AND bbb.parent = 4 323547caad4Sdrh ORDER BY bbb.title COLLATE NOCASE ASC; 32447eb16d4Sdan} { 325cdf88760Sdrh QUERY PLAN 326*8210233cSdrh |--SEARCH aaa USING INDEX aaa_333 (fk=?) 327*8210233cSdrh |--SEARCH bbb USING INTEGER PRIMARY KEY (rowid=?) 328cdf88760Sdrh `--USE TEMP B-TREE FOR ORDER BY 329547caad4Sdrh} 330cdf88760Sdrhdo_eqp_test where3-5.1 { 331547caad4Sdrh SELECT bbb.title AS tag_title 332547caad4Sdrh FROM aaa JOIN aaa AS bbb ON bbb.id = aaa.parent 333547caad4Sdrh WHERE aaa.fk = 'constant' 334547caad4Sdrh AND LENGTH(bbb.title) > 0 335547caad4Sdrh AND bbb.parent = 4 336547caad4Sdrh ORDER BY bbb.title COLLATE NOCASE ASC; 33747eb16d4Sdan} { 338cdf88760Sdrh QUERY PLAN 339*8210233cSdrh |--SEARCH aaa USING INDEX aaa_333 (fk=?) 340*8210233cSdrh |--SEARCH bbb USING INTEGER PRIMARY KEY (rowid=?) 341cdf88760Sdrh `--USE TEMP B-TREE FOR ORDER BY 342547caad4Sdrh} 343cdf88760Sdrhdo_eqp_test where3-5.2 { 344547caad4Sdrh SELECT bbb.title AS tag_title 345547caad4Sdrh FROM bbb JOIN aaa ON bbb.id = aaa.parent 346547caad4Sdrh WHERE aaa.fk = 'constant' 347547caad4Sdrh AND LENGTH(bbb.title) > 0 348547caad4Sdrh AND bbb.parent = 4 349547caad4Sdrh ORDER BY bbb.title COLLATE NOCASE ASC; 35047eb16d4Sdan} { 351cdf88760Sdrh QUERY PLAN 352*8210233cSdrh |--SEARCH aaa USING INDEX aaa_333 (fk=?) 353*8210233cSdrh |--SEARCH bbb USING INTEGER PRIMARY KEY (rowid=?) 354cdf88760Sdrh `--USE TEMP B-TREE FOR ORDER BY 355547caad4Sdrh} 356cdf88760Sdrhdo_eqp_test where3-5.3 { 357547caad4Sdrh SELECT bbb.title AS tag_title 358547caad4Sdrh FROM aaa AS bbb JOIN aaa ON bbb.id = aaa.parent 359547caad4Sdrh WHERE aaa.fk = 'constant' 360547caad4Sdrh AND LENGTH(bbb.title) > 0 361547caad4Sdrh AND bbb.parent = 4 362547caad4Sdrh ORDER BY bbb.title COLLATE NOCASE ASC; 36347eb16d4Sdan} { 364cdf88760Sdrh QUERY PLAN 365*8210233cSdrh |--SEARCH aaa USING INDEX aaa_333 (fk=?) 366*8210233cSdrh |--SEARCH bbb USING INTEGER PRIMARY KEY (rowid=?) 367cdf88760Sdrh `--USE TEMP B-TREE FOR ORDER BY 368547caad4Sdrh} 369547caad4Sdrh 370e802c5daSdrh# Name resolution with NATURAL JOIN and USING 371e802c5daSdrh# 372e802c5daSdrhdo_test where3-6.setup { 373e802c5daSdrh db eval { 374e802c5daSdrh CREATE TABLE t6w(a, w); 375e802c5daSdrh INSERT INTO t6w VALUES(1, 'w-one'); 376e802c5daSdrh INSERT INTO t6w VALUES(2, 'w-two'); 377e802c5daSdrh INSERT INTO t6w VALUES(9, 'w-nine'); 378e802c5daSdrh CREATE TABLE t6x(a, x); 379e802c5daSdrh INSERT INTO t6x VALUES(1, 'x-one'); 380e802c5daSdrh INSERT INTO t6x VALUES(3, 'x-three'); 381e802c5daSdrh INSERT INTO t6x VALUES(9, 'x-nine'); 382e802c5daSdrh CREATE TABLE t6y(a, y); 383e802c5daSdrh INSERT INTO t6y VALUES(1, 'y-one'); 384e802c5daSdrh INSERT INTO t6y VALUES(4, 'y-four'); 385e802c5daSdrh INSERT INTO t6y VALUES(9, 'y-nine'); 386e802c5daSdrh CREATE TABLE t6z(a, z); 387e802c5daSdrh INSERT INTO t6z VALUES(1, 'z-one'); 388e802c5daSdrh INSERT INTO t6z VALUES(5, 'z-five'); 389e802c5daSdrh INSERT INTO t6z VALUES(9, 'z-nine'); 390e802c5daSdrh } 391e802c5daSdrh} {} 392e802c5daSdrhset cnt 0 393e802c5daSdrhforeach predicate { 394e802c5daSdrh {} 395e802c5daSdrh {ORDER BY a} 396e802c5daSdrh {ORDER BY t6w.a} 397e802c5daSdrh {WHERE a>0} 398e802c5daSdrh {WHERE t6y.a>0} 399e802c5daSdrh {WHERE a>0 ORDER BY a} 400e802c5daSdrh} { 401e802c5daSdrh incr cnt 402e802c5daSdrh do_test where3-6.$cnt.1 { 403e802c5daSdrh set sql "SELECT * FROM t6w NATURAL JOIN t6x NATURAL JOIN t6y" 404e802c5daSdrh append sql " NATURAL JOIN t6z " 405e802c5daSdrh append sql $::predicate 406e802c5daSdrh db eval $sql 407e802c5daSdrh } {1 w-one x-one y-one z-one 9 w-nine x-nine y-nine z-nine} 408e802c5daSdrh do_test where3-6.$cnt.2 { 409e802c5daSdrh set sql "SELECT * FROM t6w JOIN t6x USING(a) JOIN t6y USING(a)" 410e802c5daSdrh append sql " JOIN t6z USING(a) " 411e802c5daSdrh append sql $::predicate 412e802c5daSdrh db eval $sql 413e802c5daSdrh } {1 w-one x-one y-one z-one 9 w-nine x-nine y-nine z-nine} 414e802c5daSdrh do_test where3-6.$cnt.3 { 415e802c5daSdrh set sql "SELECT * FROM t6w NATURAL JOIN t6x JOIN t6y USING(a)" 416e802c5daSdrh append sql " JOIN t6z USING(a) " 417e802c5daSdrh append sql $::predicate 418e802c5daSdrh db eval $sql 419e802c5daSdrh } {1 w-one x-one y-one z-one 9 w-nine x-nine y-nine z-nine} 420e802c5daSdrh do_test where3-6.$cnt.4 { 421e802c5daSdrh set sql "SELECT * FROM t6w JOIN t6x USING(a) NATURAL JOIN t6y" 422e802c5daSdrh append sql " JOIN t6z USING(a) " 423e802c5daSdrh append sql $::predicate 424e802c5daSdrh db eval $sql 425e802c5daSdrh } {1 w-one x-one y-one z-one 9 w-nine x-nine y-nine z-nine} 426e802c5daSdrh do_test where3-6.$cnt.5 { 427e802c5daSdrh set sql "SELECT * FROM t6w JOIN t6x USING(a) JOIN t6y USING(a)" 428e802c5daSdrh append sql " NATURAL JOIN t6z " 429e802c5daSdrh append sql $::predicate 430e802c5daSdrh db eval $sql 431e802c5daSdrh } {1 w-one x-one y-one z-one 9 w-nine x-nine y-nine z-nine} 432e802c5daSdrh do_test where3-6.$cnt.6 { 433e802c5daSdrh set sql "SELECT * FROM t6w JOIN t6x USING(a) NATURAL JOIN t6y" 434e802c5daSdrh append sql " NATURAL JOIN t6z " 435e802c5daSdrh append sql $::predicate 436e802c5daSdrh db eval $sql 437e802c5daSdrh } {1 w-one x-one y-one z-one 9 w-nine x-nine y-nine z-nine} 438e802c5daSdrh do_test where3-6.$cnt.7 { 439e802c5daSdrh set sql "SELECT * FROM t6w NATURAL JOIN t6x JOIN t6y USING(a)" 440e802c5daSdrh append sql " NATURAL JOIN t6z " 441e802c5daSdrh append sql $::predicate 442e802c5daSdrh db eval $sql 443e802c5daSdrh } {1 w-one x-one y-one z-one 9 w-nine x-nine y-nine z-nine} 444e802c5daSdrh do_test where3-6.$cnt.8 { 445e802c5daSdrh set sql "SELECT * FROM t6w NATURAL JOIN t6x NATURAL JOIN t6y" 446e802c5daSdrh append sql " JOIN t6z USING(a) " 447e802c5daSdrh append sql $::predicate 448e802c5daSdrh db eval $sql 449e802c5daSdrh } {1 w-one x-one y-one z-one 9 w-nine x-nine y-nine z-nine} 450e802c5daSdrh} 451e802c5daSdrh 4529d5a579cSdrhdo_execsql_test where3-7-setup { 4539d5a579cSdrh CREATE TABLE t71(x1 INTEGER PRIMARY KEY, y1); 4549d5a579cSdrh CREATE TABLE t72(x2 INTEGER PRIMARY KEY, y2); 4559d5a579cSdrh CREATE TABLE t73(x3, y3); 4569d5a579cSdrh CREATE TABLE t74(x4, y4); 4579d5a579cSdrh INSERT INTO t71 VALUES(123,234); 4589d5a579cSdrh INSERT INTO t72 VALUES(234,345); 4599d5a579cSdrh INSERT INTO t73 VALUES(123,234); 4609d5a579cSdrh INSERT INTO t74 VALUES(234,345); 4619d5a579cSdrh INSERT INTO t74 VALUES(234,678); 4629d5a579cSdrh} {} 4639d5a579cSdrhforeach disabled_opt {none omit-noop-join all} { 4649d5a579cSdrh optimization_control db all 1 4659d5a579cSdrh optimization_control db $disabled_opt 0 4669d5a579cSdrh do_execsql_test where3-7.$disabled_opt.1 { 4679d5a579cSdrh SELECT x1 FROM t71 LEFT JOIN t72 ON x2=y1; 4689d5a579cSdrh } {123} 4699d5a579cSdrh do_execsql_test where3-7.$disabled_opt.2 { 4709d5a579cSdrh SELECT x1 FROM t71 LEFT JOIN t72 ON x2=y1 WHERE y2 IS NULL; 4719d5a579cSdrh } {} 4729d5a579cSdrh do_execsql_test where3-7.$disabled_opt.3 { 4739d5a579cSdrh SELECT x1 FROM t71 LEFT JOIN t72 ON x2=y1 WHERE y2 IS NOT NULL; 4749d5a579cSdrh } {123} 4759d5a579cSdrh do_execsql_test where3-7.$disabled_opt.4 { 4769d5a579cSdrh SELECT x1 FROM t71 LEFT JOIN t72 ON x2=y1 AND y2 IS NULL; 4779d5a579cSdrh } {123} 4789d5a579cSdrh do_execsql_test where3-7.$disabled_opt.5 { 4799d5a579cSdrh SELECT x1 FROM t71 LEFT JOIN t72 ON x2=y1 AND y2 IS NOT NULL; 4809d5a579cSdrh } {123} 4819d5a579cSdrh do_execsql_test where3-7.$disabled_opt.6 { 4829d5a579cSdrh SELECT x3 FROM t73 LEFT JOIN t72 ON x2=y3; 4839d5a579cSdrh } {123} 4849d5a579cSdrh do_execsql_test where3-7.$disabled_opt.7 { 4859d5a579cSdrh SELECT DISTINCT x3 FROM t73 LEFT JOIN t72 ON x2=y3; 4869d5a579cSdrh } {123} 4879d5a579cSdrh do_execsql_test where3-7.$disabled_opt.8 { 4889d5a579cSdrh SELECT x3 FROM t73 LEFT JOIN t74 ON x4=y3; 4899d5a579cSdrh } {123 123} 4909d5a579cSdrh do_execsql_test where3-7.$disabled_opt.9 { 4919d5a579cSdrh SELECT DISTINCT x3 FROM t73 LEFT JOIN t74 ON x4=y3; 4929d5a579cSdrh } {123} 4939d5a579cSdrh} 4949d5a579cSdrh 495e802c5daSdrh 496570b935cSdrhfinish_test 497