1c49de5d9Sdrh# 2006 October 27 2c49de5d9Sdrh# 3c49de5d9Sdrh# The author disclaims copyright to this source code. In place of 4c49de5d9Sdrh# a legal notice, here is a blessing: 5c49de5d9Sdrh# 6c49de5d9Sdrh# May you do good and not evil. 7c49de5d9Sdrh# May you find forgiveness for yourself and forgive others. 8c49de5d9Sdrh# May you share freely, never taking more than you give. 9c49de5d9Sdrh# 10c49de5d9Sdrh#*********************************************************************** 11c49de5d9Sdrh# This file implements regression tests for SQLite library. The 12c49de5d9Sdrh# focus of this file is testing the use of indices in WHERE clauses. 13c49de5d9Sdrh# This file was created when support for optimizing IS NULL phrases 14c49de5d9Sdrh# was added. And so the principle purpose of this file is to test 15c49de5d9Sdrh# that IS NULL phrases are correctly optimized. But you can never 16c49de5d9Sdrh# have too many tests, so some other tests are thrown in as well. 17c49de5d9Sdrh# 18284f4acaSdanielk1977# $Id: where4.test,v 1.6 2007/12/10 05:03:48 danielk1977 Exp $ 19c49de5d9Sdrh 20c49de5d9Sdrhset testdir [file dirname $argv0] 21c49de5d9Sdrhsource $testdir/tester.tcl 223072b537Sdanset testprefix where4 23c49de5d9Sdrh 244152e677Sdanielk1977ifcapable !tclvar||!bloblit { 254152e677Sdanielk1977 finish_test 264152e677Sdanielk1977 return 274152e677Sdanielk1977} 284152e677Sdanielk1977 29c49de5d9Sdrh# Build some test data 30c49de5d9Sdrh# 31c49de5d9Sdrhdo_test where4-1.0 { 32c49de5d9Sdrh execsql { 33c49de5d9Sdrh CREATE TABLE t1(w, x, y); 34c49de5d9Sdrh CREATE INDEX i1wxy ON t1(w,x,y); 35c49de5d9Sdrh INSERT INTO t1 VALUES(1,2,3); 36c49de5d9Sdrh INSERT INTO t1 VALUES(1,NULL,3); 37c49de5d9Sdrh INSERT INTO t1 VALUES('a','b','c'); 38c49de5d9Sdrh INSERT INTO t1 VALUES('a',NULL,'c'); 39c49de5d9Sdrh INSERT INTO t1 VALUES(X'78',x'79',x'7a'); 40c49de5d9Sdrh INSERT INTO t1 VALUES(X'78',NULL,X'7A'); 41c49de5d9Sdrh INSERT INTO t1 VALUES(NULL,NULL,NULL); 42c49de5d9Sdrh SELECT count(*) FROM t1; 43c49de5d9Sdrh } 44c49de5d9Sdrh} {7} 45c49de5d9Sdrh 46c49de5d9Sdrh# Do an SQL statement. Append the search count to the end of the result. 47c49de5d9Sdrh# 48c49de5d9Sdrhproc count sql { 49c49de5d9Sdrh set ::sqlite_search_count 0 50c49de5d9Sdrh return [concat [execsql $sql] $::sqlite_search_count] 51c49de5d9Sdrh} 52c49de5d9Sdrh 53c49de5d9Sdrh# Verify that queries use an index. We are using the special variable 54c49de5d9Sdrh# "sqlite_search_count" which tallys the number of executions of MoveTo 55c49de5d9Sdrh# and Next operators in the VDBE. By verifing that the search count is 56c49de5d9Sdrh# small we can be assured that indices are being used properly. 57c49de5d9Sdrh# 58c49de5d9Sdrhdo_test where4-1.1 { 59c49de5d9Sdrh count {SELECT rowid FROM t1 WHERE w IS NULL} 60c49de5d9Sdrh} {7 2} 61e8d0c61fSdrhdo_test where4-1.1b { 62e8d0c61fSdrh unset -nocomplain null 63e8d0c61fSdrh count {SELECT rowid FROM t1 WHERE w IS $null} 64e8d0c61fSdrh} {7 2} 65c49de5d9Sdrhdo_test where4-1.2 { 66c49de5d9Sdrh count {SELECT rowid FROM t1 WHERE +w IS NULL} 67c49de5d9Sdrh} {7 6} 68c49de5d9Sdrhdo_test where4-1.3 { 69c49de5d9Sdrh count {SELECT rowid FROM t1 WHERE w=1 AND x IS NULL} 70c49de5d9Sdrh} {2 2} 71c49de5d9Sdrhdo_test where4-1.4 { 72c49de5d9Sdrh count {SELECT rowid FROM t1 WHERE w=1 AND +x IS NULL} 73c49de5d9Sdrh} {2 3} 74c49de5d9Sdrhdo_test where4-1.5 { 75c49de5d9Sdrh count {SELECT rowid FROM t1 WHERE w=1 AND x>0} 76c49de5d9Sdrh} {1 2} 77c49de5d9Sdrhdo_test where4-1.6 { 78c49de5d9Sdrh count {SELECT rowid FROM t1 WHERE w=1 AND x<9} 79cfc6ca41Sdrh} {1 2} 80c49de5d9Sdrhdo_test where4-1.7 { 81c49de5d9Sdrh count {SELECT rowid FROM t1 WHERE w=1 AND x IS NULL AND y=3} 82c49de5d9Sdrh} {2 2} 83c49de5d9Sdrhdo_test where4-1.8 { 84c49de5d9Sdrh count {SELECT rowid FROM t1 WHERE w=1 AND x IS NULL AND y>2} 85c49de5d9Sdrh} {2 2} 86c49de5d9Sdrhdo_test where4-1.9 { 87c49de5d9Sdrh count {SELECT rowid FROM t1 WHERE w='a' AND x IS NULL AND y='c'} 88c49de5d9Sdrh} {4 2} 89c49de5d9Sdrhdo_test where4-1.10 { 90c49de5d9Sdrh count {SELECT rowid FROM t1 WHERE w=x'78' AND x IS NULL} 91c49de5d9Sdrh} {6 2} 92c49de5d9Sdrhdo_test where4-1.11 { 93c49de5d9Sdrh count {SELECT rowid FROM t1 WHERE w=x'78' AND x IS NULL AND y=123} 94*b1d607deSdrh} {0} 95c49de5d9Sdrhdo_test where4-1.12 { 96c49de5d9Sdrh count {SELECT rowid FROM t1 WHERE w=x'78' AND x IS NULL AND y=x'7A'} 97c49de5d9Sdrh} {6 2} 98c49de5d9Sdrhdo_test where4-1.13 { 99c49de5d9Sdrh count {SELECT rowid FROM t1 WHERE w IS NULL AND x IS NULL} 100c49de5d9Sdrh} {7 2} 101c49de5d9Sdrhdo_test where4-1.14 { 102c49de5d9Sdrh count {SELECT rowid FROM t1 WHERE w IS NULL AND x IS NULL AND y IS NULL} 103c49de5d9Sdrh} {7 2} 104c49de5d9Sdrhdo_test where4-1.15 { 105c49de5d9Sdrh count {SELECT rowid FROM t1 WHERE w IS NULL AND x IS NULL AND y<0} 106cfc6ca41Sdrh} {1} 107c49de5d9Sdrhdo_test where4-1.16 { 108c49de5d9Sdrh count {SELECT rowid FROM t1 WHERE w IS NULL AND x IS NULL AND y>=0} 109c49de5d9Sdrh} {1} 110c49de5d9Sdrh 111c49de5d9Sdrhdo_test where4-2.1 { 112c49de5d9Sdrh execsql {SELECT rowid FROM t1 ORDER BY w, x, y} 113c49de5d9Sdrh} {7 2 1 4 3 6 5} 114c49de5d9Sdrhdo_test where4-2.2 { 115c49de5d9Sdrh execsql {SELECT rowid FROM t1 ORDER BY w DESC, x, y} 116c49de5d9Sdrh} {6 5 4 3 2 1 7} 117c49de5d9Sdrhdo_test where4-2.3 { 118c49de5d9Sdrh execsql {SELECT rowid FROM t1 ORDER BY w, x DESC, y} 119c49de5d9Sdrh} {7 1 2 3 4 5 6} 120c49de5d9Sdrh 121c49de5d9Sdrh 122c49de5d9Sdrh# Ticket #2177 123c49de5d9Sdrh# 124c49de5d9Sdrh# Suppose you have a left join where the right table of the left 125c49de5d9Sdrh# join (the one that can be NULL) has an index on two columns. 126c49de5d9Sdrh# The first indexed column is used in the ON clause of the join. 127c49de5d9Sdrh# The second indexed column is used in the WHERE clause with an IS NULL 128c49de5d9Sdrh# constraint. It is not allowed to use the IS NULL optimization to 129c49de5d9Sdrh# optimize the query because the second column might be NULL because 130c49de5d9Sdrh# the right table did not match - something the index does not know 131c49de5d9Sdrh# about. 132c49de5d9Sdrh# 133c49de5d9Sdrhdo_test where4-3.1 { 134c49de5d9Sdrh execsql { 135c49de5d9Sdrh CREATE TABLE t2(a); 136c49de5d9Sdrh INSERT INTO t2 VALUES(1); 137c49de5d9Sdrh INSERT INTO t2 VALUES(2); 138c49de5d9Sdrh INSERT INTO t2 VALUES(3); 139edb04ed9Sdrh CREATE TABLE t3(x,y,UNIQUE("x",'y' ASC)); -- Goofy syntax allowed 140c49de5d9Sdrh INSERT INTO t3 VALUES(1,11); 141c49de5d9Sdrh INSERT INTO t3 VALUES(2,NULL); 142c49de5d9Sdrh 143c49de5d9Sdrh SELECT * FROM t2 LEFT JOIN t3 ON a=x WHERE +y IS NULL; 144c49de5d9Sdrh } 145c49de5d9Sdrh} {2 2 {} 3 {} {}} 146c49de5d9Sdrhdo_test where4-3.2 { 147c49de5d9Sdrh execsql { 148c49de5d9Sdrh SELECT * FROM t2 LEFT JOIN t3 ON a=x WHERE y IS NULL; 149c49de5d9Sdrh } 150c49de5d9Sdrh} {2 2 {} 3 {} {}} 151e8d0c61fSdrhdo_test where4-3.3 { 152e8d0c61fSdrh execsql { 153e8d0c61fSdrh SELECT * FROM t2 LEFT JOIN t3 ON a=x WHERE NULL is y; 154e8d0c61fSdrh } 155e8d0c61fSdrh} {2 2 {} 3 {} {}} 156e8d0c61fSdrhdo_test where4-3.4 { 157e8d0c61fSdrh unset -nocomplain null 158e8d0c61fSdrh execsql { 159e8d0c61fSdrh SELECT * FROM t2 LEFT JOIN t3 ON a=x WHERE y IS $null; 160e8d0c61fSdrh } 161e8d0c61fSdrh} {2 2 {} 3 {} {}} 162c49de5d9Sdrh 163f2d315d0Sdrh# Ticket #2189. Probably the same bug as #2177. 164f2d315d0Sdrh# 165f2d315d0Sdrhdo_test where4-4.1 { 166f2d315d0Sdrh execsql { 167f2d315d0Sdrh CREATE TABLE test(col1 TEXT PRIMARY KEY); 168f2d315d0Sdrh INSERT INTO test(col1) values('a'); 169f2d315d0Sdrh INSERT INTO test(col1) values('b'); 170f2d315d0Sdrh INSERT INTO test(col1) values('c'); 171f2d315d0Sdrh CREATE TABLE test2(col1 TEXT PRIMARY KEY); 172f2d315d0Sdrh INSERT INTO test2(col1) values('a'); 173f2d315d0Sdrh INSERT INTO test2(col1) values('b'); 174f2d315d0Sdrh INSERT INTO test2(col1) values('c'); 175f2d315d0Sdrh SELECT * FROM test t1 LEFT OUTER JOIN test2 t2 ON t1.col1 = t2.col1 176f2d315d0Sdrh WHERE +t2.col1 IS NULL; 177f2d315d0Sdrh } 178f2d315d0Sdrh} {} 179f2d315d0Sdrhdo_test where4-4.2 { 180f2d315d0Sdrh execsql { 181f2d315d0Sdrh SELECT * FROM test t1 LEFT OUTER JOIN test2 t2 ON t1.col1 = t2.col1 182f2d315d0Sdrh WHERE t2.col1 IS NULL; 183f2d315d0Sdrh } 184f2d315d0Sdrh} {} 185f2d315d0Sdrhdo_test where4-4.3 { 186f2d315d0Sdrh execsql { 187f2d315d0Sdrh SELECT * FROM test t1 LEFT OUTER JOIN test2 t2 ON t1.col1 = t2.col1 188f2d315d0Sdrh WHERE +t1.col1 IS NULL; 189f2d315d0Sdrh } 190f2d315d0Sdrh} {} 191f2d315d0Sdrhdo_test where4-4.4 { 192f2d315d0Sdrh execsql { 193f2d315d0Sdrh SELECT * FROM test t1 LEFT OUTER JOIN test2 t2 ON t1.col1 = t2.col1 194f2d315d0Sdrh WHERE t1.col1 IS NULL; 195f2d315d0Sdrh } 196f2d315d0Sdrh} {} 197f2d315d0Sdrh 19872e8fa42Sdrh# Ticket #2273. Problems with IN operators and NULLs. 19972e8fa42Sdrh# 200284f4acaSdanielk1977ifcapable subquery { 20172e8fa42Sdrhdo_test where4-5.1 { 20272e8fa42Sdrh execsql { 203edb04ed9Sdrh -- Allow the 'x' syntax for backwards compatibility 204edb04ed9Sdrh CREATE TABLE t4(x,y,z,PRIMARY KEY('x' ASC, "y" ASC)); 20572e8fa42Sdrh } 20672e8fa42Sdrh execsql { 20772e8fa42Sdrh SELECT * 20872e8fa42Sdrh FROM t2 LEFT JOIN t4 b1 20972e8fa42Sdrh LEFT JOIN t4 b2 ON b2.x=b1.x AND b2.y IN (b1.y); 21072e8fa42Sdrh } 21172e8fa42Sdrh} {1 {} {} {} {} {} {} 2 {} {} {} {} {} {} 3 {} {} {} {} {} {}} 21272e8fa42Sdrhdo_test where4-5.2 { 21372e8fa42Sdrh execsql { 21472e8fa42Sdrh INSERT INTO t4 VALUES(1,1,11); 21572e8fa42Sdrh INSERT INTO t4 VALUES(1,2,12); 21672e8fa42Sdrh INSERT INTO t4 VALUES(1,3,13); 21772e8fa42Sdrh INSERT INTO t4 VALUES(2,2,22); 21872e8fa42Sdrh SELECT rowid FROM t4 WHERE x IN (1,9,2,5) AND y IN (1,3,NULL,2) AND z!=13; 21972e8fa42Sdrh } 22072e8fa42Sdrh} {1 2 4} 22172e8fa42Sdrhdo_test where4-5.3 { 22272e8fa42Sdrh execsql { 22372e8fa42Sdrh SELECT rowid FROM t4 WHERE x IN (1,9,NULL,2) AND y IN (1,3,2) AND z!=13; 22472e8fa42Sdrh } 22572e8fa42Sdrh} {1 2 4} 22672e8fa42Sdrhdo_test where4-6.1 { 22772e8fa42Sdrh execsql { 22872e8fa42Sdrh CREATE TABLE t5(a,b,c,d,e,f,UNIQUE(a,b,c,d,e,f)); 22972e8fa42Sdrh INSERT INTO t5 VALUES(1,1,1,1,1,11111); 23072e8fa42Sdrh INSERT INTO t5 VALUES(2,2,2,2,2,22222); 23172e8fa42Sdrh INSERT INTO t5 VALUES(1,2,3,4,5,12345); 23272e8fa42Sdrh INSERT INTO t5 VALUES(2,3,4,5,6,23456); 23372e8fa42Sdrh } 23472e8fa42Sdrh execsql { 23572e8fa42Sdrh SELECT rowid FROM t5 23672e8fa42Sdrh WHERE a IN (1,9,2) AND b=2 AND c IN (1,2,3,4) AND d>0 23772e8fa42Sdrh } 23872e8fa42Sdrh} {3 2} 23972e8fa42Sdrhdo_test where4-6.2 { 24072e8fa42Sdrh execsql { 24172e8fa42Sdrh SELECT rowid FROM t5 24272e8fa42Sdrh WHERE a IN (1,NULL,2) AND b=2 AND c IN (1,2,3,4) AND d>0 24372e8fa42Sdrh } 24472e8fa42Sdrh} {3 2} 24572e8fa42Sdrhdo_test where4-7.1 { 24672e8fa42Sdrh execsql { 24772e8fa42Sdrh CREATE TABLE t6(y,z,PRIMARY KEY(y,z)); 24872e8fa42Sdrh } 24972e8fa42Sdrh execsql { 25072e8fa42Sdrh SELECT * FROM t6 WHERE y=NULL AND z IN ('hello'); 25172e8fa42Sdrh } 25272e8fa42Sdrh} {} 253f2d315d0Sdrh 254c49de5d9Sdrhintegrity_check {where4-99.0} 255c49de5d9Sdrh 25639984cdcSdanielk1977do_test where4-7.1 { 25739984cdcSdanielk1977 execsql { 25839984cdcSdanielk1977 BEGIN; 25939984cdcSdanielk1977 CREATE TABLE t8(a, b, c, d); 26039984cdcSdanielk1977 CREATE INDEX t8_i ON t8(a, b, c); 26139984cdcSdanielk1977 CREATE TABLE t7(i); 26239984cdcSdanielk1977 26339984cdcSdanielk1977 INSERT INTO t7 VALUES(1); 26439984cdcSdanielk1977 INSERT INTO t7 SELECT i*2 FROM t7; 26539984cdcSdanielk1977 INSERT INTO t7 SELECT i*2 FROM t7; 26639984cdcSdanielk1977 INSERT INTO t7 SELECT i*2 FROM t7; 26739984cdcSdanielk1977 INSERT INTO t7 SELECT i*2 FROM t7; 26839984cdcSdanielk1977 INSERT INTO t7 SELECT i*2 FROM t7; 26939984cdcSdanielk1977 INSERT INTO t7 SELECT i*2 FROM t7; 27039984cdcSdanielk1977 27139984cdcSdanielk1977 COMMIT; 27239984cdcSdanielk1977 } 27339984cdcSdanielk1977} {} 27439984cdcSdanielk1977 27539984cdcSdanielk1977# At one point the sub-select inside the aggregate sum() function in the 27639984cdcSdanielk1977# following query was leaking a couple of stack entries. This query 27739984cdcSdanielk1977# runs the SELECT in a loop enough times that an assert() fails. Or rather, 27839984cdcSdanielk1977# did fail before the bug was fixed. 27939984cdcSdanielk1977# 28039984cdcSdanielk1977do_test where4-7.2 { 28139984cdcSdanielk1977 execsql { 28239984cdcSdanielk1977 SELECT sum(( 28339984cdcSdanielk1977 SELECT d FROM t8 WHERE a = i AND b = i AND c < NULL 28439984cdcSdanielk1977 )) FROM t7; 28539984cdcSdanielk1977 } 28639984cdcSdanielk1977} {{}} 28739984cdcSdanielk1977 288284f4acaSdanielk1977}; #ifcapable subquery 289284f4acaSdanielk1977 2903072b537Sdan#------------------------------------------------------------------------- 2913072b537Sdan# Verify that "IS ?" with a NULL bound to the variable also functions 2923072b537Sdan# correctly. 2933072b537Sdan 2943072b537Sdanunset -nocomplain null 2953072b537Sdan 2963072b537Sdando_execsql_test 8.1 { 2973072b537Sdan CREATE TABLE u9(a UNIQUE, b); 2983072b537Sdan INSERT INTO u9 VALUES(NULL, 1); 2993072b537Sdan INSERT INTO u9 VALUES(NULL, 2); 3003072b537Sdan} 3013072b537Sdando_execsql_test 8.2 { SELECT * FROM u9 WHERE a IS NULL } {{} 1 {} 2} 3023072b537Sdando_execsql_test 8.2 { SELECT * FROM u9 WHERE a IS $null } {{} 1 {} 2} 3033072b537Sdan 3043072b537Sdan 3053072b537Sdan 3063072b537Sdan 307c49de5d9Sdrhfinish_test 308