122d6a53aSdrh# 2005 September 19 222d6a53aSdrh# 322d6a53aSdrh# The author disclaims copyright to this source code. In place of 422d6a53aSdrh# a legal notice, here is a blessing: 522d6a53aSdrh# 622d6a53aSdrh# May you do good and not evil. 722d6a53aSdrh# May you find forgiveness for yourself and forgive others. 822d6a53aSdrh# May you share freely, never taking more than you give. 922d6a53aSdrh# 1022d6a53aSdrh#*********************************************************************** 1122d6a53aSdrh# This file implements regression tests for SQLite library. 1222d6a53aSdrh# 1322d6a53aSdrh# This file implements tests for left outer joins containing ON 1422d6a53aSdrh# clauses that restrict the scope of the left term of the join. 1522d6a53aSdrh# 1622d6a53aSdrh 1722d6a53aSdrhset testdir [file dirname $argv0] 1822d6a53aSdrhsource $testdir/tester.tcl 1992ddb3bdSdanset testprefix join5 2022d6a53aSdrh 2122d6a53aSdrh 2222d6a53aSdrhdo_test join5-1.1 { 2322d6a53aSdrh execsql { 2422d6a53aSdrh BEGIN; 2522d6a53aSdrh CREATE TABLE t1(a integer primary key, b integer, c integer); 2622d6a53aSdrh CREATE TABLE t2(x integer primary key, y); 2722d6a53aSdrh CREATE TABLE t3(p integer primary key, q); 2822d6a53aSdrh INSERT INTO t3 VALUES(11,'t3-11'); 2922d6a53aSdrh INSERT INTO t3 VALUES(12,'t3-12'); 3022d6a53aSdrh INSERT INTO t2 VALUES(11,'t2-11'); 3122d6a53aSdrh INSERT INTO t2 VALUES(12,'t2-12'); 3222d6a53aSdrh INSERT INTO t1 VALUES(1, 5, 0); 3322d6a53aSdrh INSERT INTO t1 VALUES(2, 11, 2); 3422d6a53aSdrh INSERT INTO t1 VALUES(3, 12, 1); 3522d6a53aSdrh COMMIT; 3622d6a53aSdrh } 3722d6a53aSdrh} {} 3822d6a53aSdrhdo_test join5-1.2 { 3922d6a53aSdrh execsql { 4022d6a53aSdrh select * from t1 left join t2 on t1.b=t2.x and t1.c=1 4122d6a53aSdrh } 4222d6a53aSdrh} {1 5 0 {} {} 2 11 2 {} {} 3 12 1 12 t2-12} 4322d6a53aSdrhdo_test join5-1.3 { 4422d6a53aSdrh execsql { 4522d6a53aSdrh select * from t1 left join t2 on t1.b=t2.x where t1.c=1 4622d6a53aSdrh } 4722d6a53aSdrh} {3 12 1 12 t2-12} 4822d6a53aSdrhdo_test join5-1.4 { 4922d6a53aSdrh execsql { 5022d6a53aSdrh select * from t1 left join t2 on t1.b=t2.x and t1.c=1 5122d6a53aSdrh left join t3 on t1.b=t3.p and t1.c=2 5222d6a53aSdrh } 5322d6a53aSdrh} {1 5 0 {} {} {} {} 2 11 2 {} {} 11 t3-11 3 12 1 12 t2-12 {} {}} 5422d6a53aSdrhdo_test join5-1.5 { 5522d6a53aSdrh execsql { 5622d6a53aSdrh select * from t1 left join t2 on t1.b=t2.x and t1.c=1 5722d6a53aSdrh left join t3 on t1.b=t3.p where t1.c=2 5822d6a53aSdrh } 5922d6a53aSdrh} {2 11 2 {} {} 11 t3-11} 6022d6a53aSdrh 610a168377Sdrh# Ticket #2403 620a168377Sdrh# 630a168377Sdrhdo_test join5-2.1 { 640a168377Sdrh execsql { 650a168377Sdrh CREATE TABLE ab(a,b); 660a168377Sdrh INSERT INTO "ab" VALUES(1,2); 670a168377Sdrh INSERT INTO "ab" VALUES(3,NULL); 680a168377Sdrh 690a168377Sdrh CREATE TABLE xy(x,y); 700a168377Sdrh INSERT INTO "xy" VALUES(2,3); 710a168377Sdrh INSERT INTO "xy" VALUES(NULL,1); 720a168377Sdrh } 730a168377Sdrh execsql {SELECT * FROM xy LEFT JOIN ab ON 0} 740a168377Sdrh} {2 3 {} {} {} 1 {} {}} 750a168377Sdrhdo_test join5-2.2 { 760a168377Sdrh execsql {SELECT * FROM xy LEFT JOIN ab ON 1} 770a168377Sdrh} {2 3 1 2 2 3 3 {} {} 1 1 2 {} 1 3 {}} 780a168377Sdrhdo_test join5-2.3 { 790a168377Sdrh execsql {SELECT * FROM xy LEFT JOIN ab ON NULL} 800a168377Sdrh} {2 3 {} {} {} 1 {} {}} 810a168377Sdrhdo_test join5-2.4 { 820a168377Sdrh execsql {SELECT * FROM xy LEFT JOIN ab ON 0 WHERE 0} 830a168377Sdrh} {} 840a168377Sdrhdo_test join5-2.5 { 850a168377Sdrh execsql {SELECT * FROM xy LEFT JOIN ab ON 1 WHERE 0} 860a168377Sdrh} {} 870a168377Sdrhdo_test join5-2.6 { 880a168377Sdrh execsql {SELECT * FROM xy LEFT JOIN ab ON NULL WHERE 0} 890a168377Sdrh} {} 900a168377Sdrhdo_test join5-2.7 { 910a168377Sdrh execsql {SELECT * FROM xy LEFT JOIN ab ON 0 WHERE 1} 920a168377Sdrh} {2 3 {} {} {} 1 {} {}} 930a168377Sdrhdo_test join5-2.8 { 940a168377Sdrh execsql {SELECT * FROM xy LEFT JOIN ab ON 1 WHERE 1} 950a168377Sdrh} {2 3 1 2 2 3 3 {} {} 1 1 2 {} 1 3 {}} 960a168377Sdrhdo_test join5-2.9 { 970a168377Sdrh execsql {SELECT * FROM xy LEFT JOIN ab ON NULL WHERE 1} 980a168377Sdrh} {2 3 {} {} {} 1 {} {}} 990a168377Sdrhdo_test join5-2.10 { 1000a168377Sdrh execsql {SELECT * FROM xy LEFT JOIN ab ON 0 WHERE NULL} 1010a168377Sdrh} {} 1020a168377Sdrhdo_test join5-2.11 { 1030a168377Sdrh execsql {SELECT * FROM xy LEFT JOIN ab ON 1 WHERE NULL} 1040a168377Sdrh} {} 1050a168377Sdrhdo_test join5-2.12 { 1060a168377Sdrh execsql {SELECT * FROM xy LEFT JOIN ab ON NULL WHERE NULL} 1070a168377Sdrh} {} 1080a168377Sdrh 10972673a24Sdrh# Ticket https://www.sqlite.org/src/tktview/6f2222d550f5b0ee7ed37601 11072673a24Sdrh# Incorrect output on a LEFT JOIN. 11172673a24Sdrh# 11272673a24Sdrhdo_execsql_test join5-3.1 { 11372673a24Sdrh DROP TABLE IF EXISTS t1; 11472673a24Sdrh DROP TABLE IF EXISTS t2; 11572673a24Sdrh DROP TABLE IF EXISTS t3; 11672673a24Sdrh CREATE TABLE x1(a); 11772673a24Sdrh INSERT INTO x1 VALUES(1); 11872673a24Sdrh CREATE TABLE x2(b NOT NULL); 11972673a24Sdrh CREATE TABLE x3(c, d); 12072673a24Sdrh INSERT INTO x3 VALUES('a', NULL); 12172673a24Sdrh INSERT INTO x3 VALUES('b', NULL); 12272673a24Sdrh INSERT INTO x3 VALUES('c', NULL); 12372673a24Sdrh SELECT * FROM x1 LEFT JOIN x2 LEFT JOIN x3 ON x3.d = x2.b; 12472673a24Sdrh} {1 {} {} {}} 12572673a24Sdrhdo_execsql_test join5-3.2 { 12672673a24Sdrh DROP TABLE IF EXISTS t1; 12772673a24Sdrh DROP TABLE IF EXISTS t2; 12872673a24Sdrh DROP TABLE IF EXISTS t3; 12972673a24Sdrh DROP TABLE IF EXISTS t4; 13072673a24Sdrh DROP TABLE IF EXISTS t5; 13172673a24Sdrh CREATE TABLE t1(x text NOT NULL, y text); 13272673a24Sdrh CREATE TABLE t2(u text NOT NULL, x text NOT NULL); 13372673a24Sdrh CREATE TABLE t3(w text NOT NULL, v text); 13472673a24Sdrh CREATE TABLE t4(w text NOT NULL, z text NOT NULL); 13572673a24Sdrh CREATE TABLE t5(z text NOT NULL, m text); 13672673a24Sdrh INSERT INTO t1 VALUES('f6d7661f-4efe-4c90-87b5-858e61cd178b',NULL); 13772673a24Sdrh INSERT INTO t1 VALUES('f6ea82c3-2cad-45ce-ae8f-3ddca4fb2f48',NULL); 13872673a24Sdrh INSERT INTO t1 VALUES('f6f47499-ecb4-474b-9a02-35be73c235e5',NULL); 13972673a24Sdrh INSERT INTO t1 VALUES('56f47499-ecb4-474b-9a02-35be73c235e5',NULL); 14072673a24Sdrh INSERT INTO t3 VALUES('007f2033-cb20-494c-b135-a1e4eb66130c', 14172673a24Sdrh 'f6d7661f-4efe-4c90-87b5-858e61cd178b'); 14272673a24Sdrh SELECT * 14372673a24Sdrh FROM t3 14472673a24Sdrh INNER JOIN t1 ON t1.x= t3.v AND t1.y IS NULL 14572673a24Sdrh LEFT JOIN t4 ON t4.w = t3.w 14672673a24Sdrh LEFT JOIN t5 ON t5.z = t4.z 14772673a24Sdrh LEFT JOIN t2 ON t2.u = t5.m 14872673a24Sdrh LEFT JOIN t1 xyz ON xyz.y = t2.x; 14972673a24Sdrh} {007f2033-cb20-494c-b135-a1e4eb66130c f6d7661f-4efe-4c90-87b5-858e61cd178b f6d7661f-4efe-4c90-87b5-858e61cd178b {} {} {} {} {} {} {} {} {}} 15072673a24Sdrhdo_execsql_test join5-3.3 { 15172673a24Sdrh DROP TABLE IF EXISTS x1; 15272673a24Sdrh DROP TABLE IF EXISTS x2; 15372673a24Sdrh DROP TABLE IF EXISTS x3; 15472673a24Sdrh CREATE TABLE x1(a); 15572673a24Sdrh INSERT INTO x1 VALUES(1); 15672673a24Sdrh CREATE TABLE x2(b NOT NULL); 15772673a24Sdrh CREATE TABLE x3(c, d); 15872673a24Sdrh INSERT INTO x3 VALUES('a', NULL); 15972673a24Sdrh INSERT INTO x3 VALUES('b', NULL); 16072673a24Sdrh INSERT INTO x3 VALUES('c', NULL); 16172673a24Sdrh SELECT * FROM x1 LEFT JOIN x2 JOIN x3 WHERE x3.d = x2.b; 16272673a24Sdrh} {} 16322d6a53aSdrh 16438978dd4Sdrh# Ticket https://www.sqlite.org/src/tktview/c2a19d81652f40568c770c43 on 16538978dd4Sdrh# 2015-08-20. LEFT JOIN and the push-down optimization. 16638978dd4Sdrh# 167f6e6f023Sdrhdo_execsql_test join5-4.1 { 16838978dd4Sdrh SELECT * 16938978dd4Sdrh FROM ( 17038978dd4Sdrh SELECT 'apple' fruit 17138978dd4Sdrh UNION ALL SELECT 'banana' 17238978dd4Sdrh ) a 17338978dd4Sdrh JOIN ( 17438978dd4Sdrh SELECT 'apple' fruit 17538978dd4Sdrh UNION ALL SELECT 'banana' 17638978dd4Sdrh ) b ON a.fruit=b.fruit 17738978dd4Sdrh LEFT JOIN ( 17838978dd4Sdrh SELECT 1 isyellow 17938978dd4Sdrh ) c ON b.fruit='banana'; 18038978dd4Sdrh} {apple apple {} banana banana 1} 181f6e6f023Sdrhdo_execsql_test join5-4.2 { 18238978dd4Sdrh SELECT * 18338978dd4Sdrh FROM (SELECT 'apple' fruit UNION ALL SELECT 'banana') 18438978dd4Sdrh LEFT JOIN (SELECT 1) ON fruit='banana'; 18538978dd4Sdrh} {apple {} banana 1} 18638978dd4Sdrh 18792ddb3bdSdan#------------------------------------------------------------------------- 18892ddb3bdSdando_execsql_test 5.0 { 18992ddb3bdSdan CREATE TABLE y1(x, y, z); 19092ddb3bdSdan INSERT INTO y1 VALUES(0, 0, 1); 19192ddb3bdSdan CREATE TABLE y2(a); 19292ddb3bdSdan} 19392ddb3bdSdan 19492ddb3bdSdando_execsql_test 5.1 { 19592ddb3bdSdan SELECT count(z) FROM y1 LEFT JOIN y2 ON x GROUP BY y; 19692ddb3bdSdan} 1 19792ddb3bdSdan 19892ddb3bdSdando_execsql_test 5.2 { 19992ddb3bdSdan SELECT count(z) FROM ( SELECT * FROM y1 ) LEFT JOIN y2 ON x GROUP BY y; 20092ddb3bdSdan} 1 20192ddb3bdSdan 20292ddb3bdSdando_execsql_test 5.3 { 20392ddb3bdSdan CREATE VIEW v1 AS SELECT x, y, z FROM y1; 20492ddb3bdSdan SELECT count(z) FROM v1 LEFT JOIN y2 ON x GROUP BY y; 20592ddb3bdSdan} 1 20692ddb3bdSdan 20792ddb3bdSdando_execsql_test 5.4 { 20892ddb3bdSdan SELECT count(z) FROM ( SELECT * FROM y1 ) LEFT JOIN y2 ON x 20992ddb3bdSdan} 1 21092ddb3bdSdan 21192ddb3bdSdando_execsql_test 5.5 { 21292ddb3bdSdan SELECT * FROM ( SELECT * FROM y1 ) LEFT JOIN y2 ON x 21392ddb3bdSdan} {0 0 1 {}} 21492ddb3bdSdan 2154da04f78Sdan#------------------------------------------------------------------------- 2164da04f78Sdan# 2174da04f78Sdanreset_db 2184da04f78Sdando_execsql_test 6.1 { 2194da04f78Sdan CREATE TABLE t1(x); 2204da04f78Sdan INSERT INTO t1 VALUES(1); 2214da04f78Sdan 2224da04f78Sdan CREATE TABLE t2(y INTEGER PRIMARY KEY,a,b); 2234da04f78Sdan INSERT INTO t2 VALUES(1,2,3); 2244da04f78Sdan CREATE INDEX t2a ON t2(a); 2254da04f78Sdan CREATE INDEX t2b ON t2(b); 2264da04f78Sdan} 2274da04f78Sdan 2284da04f78Sdando_execsql_test 6.2 { 2294da04f78Sdan SELECT * FROM t1 LEFT JOIN t2 ON a=2 OR b=3 WHERE y IS NULL; 2304da04f78Sdan} {} 2314da04f78Sdan 2324da04f78Sdando_execsql_test 6.3.1 { 2334da04f78Sdan CREATE TABLE t3(x); 2344da04f78Sdan INSERT INTO t3 VALUES(1); 2354da04f78Sdan CREATE TABLE t4(y, z); 2364da04f78Sdan SELECT ifnull(z, '!!!') FROM t3 LEFT JOIN t4 ON (x=y); 2374da04f78Sdan} {!!!} 2384da04f78Sdan 2394da04f78Sdando_execsql_test 6.3.2 { 2404da04f78Sdan CREATE INDEX t4i ON t4(y, ifnull(z, '!!!')); 2414da04f78Sdan SELECT ifnull(z, '!!!') FROM t3 LEFT JOIN t4 ON (x=y); 2424da04f78Sdan} {!!!} 2434da04f78Sdan 2448851e100Sdrh# 2019-02-08 https://sqlite.org/src/info/4e8e4857d32d401f 2458851e100Sdrhreset_db 2468851e100Sdrhdo_execsql_test 6.100 { 2478851e100Sdrh CREATE TABLE t1(aa, bb); 2488851e100Sdrh CREATE INDEX t1x1 on t1(abs(aa), abs(bb)); 2498851e100Sdrh INSERT INTO t1 VALUES(-2,-3),(+2,-3),(-2,+3),(+2,+3); 2508851e100Sdrh SELECT * FROM (t1) 2518851e100Sdrh WHERE ((abs(aa)=1 AND 1=2) OR abs(aa)=2) 2528851e100Sdrh AND abs(bb)=3 2538851e100Sdrh ORDER BY +1, +2; 2548851e100Sdrh} {-2 -3 -2 3 2 -3 2 3} 2558851e100Sdrh 256820fcd2cSdan#------------------------------------------------------------------------- 257820fcd2cSdan# 258820fcd2cSdanreset_db 259820fcd2cSdando_execsql_test 7.0 { 260820fcd2cSdan CREATE TABLE t1(x); 261820fcd2cSdan INSERT INTO t1 VALUES(1); 262820fcd2cSdan} 263820fcd2cSdan 264820fcd2cSdando_execsql_test 7.1 { 265820fcd2cSdan CREATE TABLE t2(x, y, z); 266820fcd2cSdan CREATE INDEX t2xy ON t2(x, y); 267820fcd2cSdan WITH s(i) AS ( 268820fcd2cSdan SELECT 1 UNION ALL SELECT i+1 FROM s WHERE i<50000 269820fcd2cSdan ) 270820fcd2cSdan INSERT INTO t2 SELECT i/10, i, NULL FROM s; 271820fcd2cSdan ANALYZE; 272820fcd2cSdan} 273820fcd2cSdan 274820fcd2cSdando_eqp_test 7.2 { 275820fcd2cSdan SELECT * FROM t1 LEFT JOIN t2 ON ( 276820fcd2cSdan t2.x = t1.x AND (t2.y=? OR (t2.y=? AND t2.z IS NOT NULL)) 277820fcd2cSdan ); 278820fcd2cSdan} { 279b3f0276bSdrh QUERY PLAN 2808210233cSdrh |--SCAN t1 2815d72d924Sdrh `--MULTI-INDEX OR 282bd462bccSdrh |--INDEX 1 283c583719bSdrh | `--SEARCH t2 USING INDEX t2xy (x=? AND y=?) LEFT-JOIN 284bd462bccSdrh `--INDEX 2 285c583719bSdrh `--SEARCH t2 USING INDEX t2xy (x=? AND y=?) LEFT-JOIN 286820fcd2cSdan} 287820fcd2cSdan 288820fcd2cSdando_execsql_test 7.3 { 289820fcd2cSdan CREATE TABLE t3(x); 290820fcd2cSdan 291820fcd2cSdan CREATE TABLE t4(x, y, z); 292820fcd2cSdan CREATE INDEX t4xy ON t4(x, y); 293820fcd2cSdan CREATE INDEX t4xz ON t4(x, z); 294820fcd2cSdan 295820fcd2cSdan WITH s(i) AS ( SELECT 1 UNION ALL SELECT i+1 FROM s WHERE i<50000) 296820fcd2cSdan INSERT INTO t4 SELECT i/10, i, i FROM s; 297820fcd2cSdan 298820fcd2cSdan ANALYZE; 299820fcd2cSdan} 300820fcd2cSdan 301820fcd2cSdando_eqp_test 7.4 { 302820fcd2cSdan SELECT * FROM t3 LEFT JOIN t4 ON (t4.x = t3.x) WHERE (t4.y = ? OR t4.z = ?); 303820fcd2cSdan} { 304b3f0276bSdrh QUERY PLAN 3058210233cSdrh |--SCAN t3 306c583719bSdrh `--SEARCH t4 USING INDEX t4xz (x=?) LEFT-JOIN 307be341502Sdrh} 308be341502Sdrhdo_eqp_test 7.4b { 309be341502Sdrh SELECT * FROM t3 CROSS JOIN t4 ON (t4.x = t3.x) WHERE (+t4.y = ? OR t4.z = ?); 310be341502Sdrh} { 311be341502Sdrh QUERY PLAN 312be341502Sdrh |--SCAN t3 313a11c5e22Sdrh |--BLOOM FILTER ON t4 (x=?) 3148210233cSdrh `--SEARCH t4 USING INDEX t4xz (x=?) 315820fcd2cSdan} 316820fcd2cSdan 3177ac0e562Sdanreset_db 3187ac0e562Sdando_execsql_test 8.0 { 3197ac0e562Sdan CREATE TABLE t0 (c0, c1, PRIMARY KEY (c0, c1)); 3207ac0e562Sdan CREATE TABLE t1 (c0); 3217ac0e562Sdan 3227ac0e562Sdan INSERT INTO t1 VALUES (2); 3237ac0e562Sdan 3247ac0e562Sdan INSERT INTO t0 VALUES(0, 10); 3257ac0e562Sdan INSERT INTO t0 VALUES(1, 10); 3267ac0e562Sdan INSERT INTO t0 VALUES(2, 10); 3277ac0e562Sdan INSERT INTO t0 VALUES(3, 10); 3287ac0e562Sdan} 3297ac0e562Sdan 3307ac0e562Sdando_execsql_test 8.1 { 3317ac0e562Sdan SELECT * FROM t0, t1 3327ac0e562Sdan WHERE (t0.c1 >= 1 OR t0.c1 < 1) AND t0.c0 IN (1, t1.c0) ORDER BY 1; 3337ac0e562Sdan} { 3347ac0e562Sdan 1 10 2 3357ac0e562Sdan 2 10 2 3367ac0e562Sdan} 3377ac0e562Sdan 33887fb37efSdrh 33987fb37efSdrh# 2022-01-31 dbsqlfuzz 787d9bd73164c6f0c85469e2e48b2aff19af6938 34087fb37efSdrh# 34187fb37efSdrhreset_db 34287fb37efSdrhdo_execsql_test 9.1 { 34387fb37efSdrh CREATE TABLE t1(a ,b FLOAT); 34487fb37efSdrh INSERT INTO t1 VALUES(1,1); 34587fb37efSdrh CREATE INDEX t1x1 ON t1(a,b,a,a,a,a,a,a,a,a,a,b); 34687fb37efSdrh ANALYZE sqlite_schema; 34787fb37efSdrh INSERT INTO sqlite_stat1 VALUES('t1','t1x1','648 324 81 81 81 81 81 81 81081 81 81 81'); 34887fb37efSdrh ANALYZE sqlite_schema; 34987fb37efSdrh SELECT a FROM (SELECT a FROM t1 NATURAL LEFT JOIN t1) NATURAL LEFT JOIN t1 WHERE (rowid,1)<=(5,0); 35087fb37efSdrh} {1} 35187fb37efSdrh 35256945695Sdrh# 2022-03-02 https://sqlite.org/forum/info/50a1bbe08ce4c29c 35356945695Sdrh# Bloom-filter pulldown is incompatible with skip-scan. 35456945695Sdrh# 35556945695Sdrhreset_db 35656945695Sdrhdo_execsql_test 10.1 { 35756945695Sdrh CREATE TABLE t1(x INT); 35856945695Sdrh WITH RECURSIVE c(x) AS (VALUES(1) UNION ALL SELECT x+1 FROM c WHERE x<20) 35956945695Sdrh INSERT INTO t1(x) SELECT 0 FROM c; 36056945695Sdrh CREATE INDEX t1x1 ON t1(x BETWEEN 0 AND 10, x); 36156945695Sdrh ANALYZE; 36256945695Sdrh DELETE FROM t1; 36356945695Sdrh INSERT INTO t1 VALUES(0),(0); 36456945695Sdrh CREATE VIEW v1 AS SELECT * FROM t1 NATURAL JOIN t1 WHERE (x BETWEEN 0 AND 10) OR true; 36556945695Sdrh CREATE VIEW v2 AS SELECT * FROM v1 NATURAL JOIN v1; 36656945695Sdrh CREATE VIEW v3 AS SELECT * FROM v2, v1 USING (x) GROUP BY x; 36756945695Sdrh SELECT x FROM v3; 36856945695Sdrh} {0} 36956945695Sdrh 370be341502Sdrh# 2022-03-24 https://sqlite.org/forum/forumpost/031e262a89b6a9d2 371be341502Sdrh# Bloom-filter on a LEFT JOIN with NULL-based WHERE constraints. 372be341502Sdrh# 373be341502Sdrhreset_db 374be341502Sdrhdo_execsql_test 11.1 { 375be341502Sdrh CREATE TABLE t1(a INTEGER PRIMARY KEY, b INT); 376be341502Sdrh CREATE TABLE t2(c INTEGER PRIMARY KEY, d INT); 377be341502Sdrh WITH RECURSIVE c(x) AS (VALUES(1) UNION ALL SELECT x+1 FROM c WHERE x<8) 378be341502Sdrh INSERT INTO t1(a,b) SELECT x, 10*x FROM c; 379be341502Sdrh INSERT INTO t2(c,d) SELECT b*2, 100*a FROM t1; 380be341502Sdrh ANALYZE; 381be341502Sdrh DELETE FROM sqlite_stat1; 382be341502Sdrh INSERT INTO sqlite_stat1(tbl,idx,stat) VALUES 383be341502Sdrh ('t1',NULL,150105),('t2',NULL,98747); 384be341502Sdrh ANALYZE sqlite_schema; 385be341502Sdrh} {} 386be341502Sdrhdo_execsql_test 11.2 { 387be341502Sdrh SELECT count(*) FROM t1 LEFT JOIN t2 ON c=b WHERE d IS NULL; 388be341502Sdrh} {4} 389be341502Sdrhdo_execsql_test 11.3 { 390be341502Sdrh SELECT count(*) FROM t1 LEFT JOIN t2 ON c=b WHERE d=100; 391be341502Sdrh} {1} 392be341502Sdrhdo_execsql_test 11.4 { 393be341502Sdrh SELECT count(*) FROM t1 LEFT JOIN t2 ON c=b WHERE d>=300; 394be341502Sdrh} {2} 395be341502Sdrh 396*8aa7f4d8Sdrh# 2022-05-03 https://sqlite.org/forum/forumpost/2482b32700384a0f 397*8aa7f4d8Sdrh# Bloom-filter pull-down does not handle NOT NULL constraints correctly. 398*8aa7f4d8Sdrh# 399*8aa7f4d8Sdrhreset_db 400*8aa7f4d8Sdrhdo_execsql_test 12.1 { 401*8aa7f4d8Sdrh CREATE TABLE t1(a INT, b INT, c INT); 402*8aa7f4d8Sdrh WITH RECURSIVE c(x) AS (VALUES(1) UNION ALL SELECT x+1 FROM c WHERE x<100) 403*8aa7f4d8Sdrh INSERT INTO t1(a,b,c) SELECT x, x*1000, x*1000000 FROM c; 404*8aa7f4d8Sdrh CREATE TABLE t2(b INT, x INT); 405*8aa7f4d8Sdrh INSERT INTO t2(b,x) SELECT b, a FROM t1 WHERE a%3==0; 406*8aa7f4d8Sdrh CREATE INDEX t2b ON t2(b); 407*8aa7f4d8Sdrh CREATE TABLE t3(c INT, y INT); 408*8aa7f4d8Sdrh INSERT INTO t3(c,y) SELECT c, a FROM t1 WHERE a%4==0; 409*8aa7f4d8Sdrh CREATE INDEX t3c ON t3(c); 410*8aa7f4d8Sdrh INSERT INTO t1(a,b,c) VALUES(200, 200000, NULL); 411*8aa7f4d8Sdrh ANALYZE; 412*8aa7f4d8Sdrh} {} 413*8aa7f4d8Sdrhdo_execsql_test 12.2 { 414*8aa7f4d8Sdrh SELECT * FROM t1 NATURAL JOIN t2 NATURAL JOIN t3 WHERE x>0 AND y>0 415*8aa7f4d8Sdrh ORDER BY +a; 416*8aa7f4d8Sdrh} { 417*8aa7f4d8Sdrh 12 12000 12000000 12 12 418*8aa7f4d8Sdrh 24 24000 24000000 24 24 419*8aa7f4d8Sdrh 36 36000 36000000 36 36 420*8aa7f4d8Sdrh 48 48000 48000000 48 48 421*8aa7f4d8Sdrh 60 60000 60000000 60 60 422*8aa7f4d8Sdrh 72 72000 72000000 72 72 423*8aa7f4d8Sdrh 84 84000 84000000 84 84 424*8aa7f4d8Sdrh 96 96000 96000000 96 96 425*8aa7f4d8Sdrh} 426*8aa7f4d8Sdrh 427*8aa7f4d8Sdrh 428be341502Sdrh 42956945695Sdrh 43022d6a53aSdrhfinish_test 431