1# 2008 September 1 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# 12# $Id: in4.test,v 1.4 2009/06/05 17:09:12 drh Exp $ 13 14set testdir [file dirname $argv0] 15source $testdir/tester.tcl 16 17do_test in4-1.1 { 18 execsql { 19 CREATE TABLE t1(a, b); 20 CREATE INDEX i1 ON t1(a); 21 } 22} {} 23do_test in4-1.2 { 24 execsql { 25 SELECT * FROM t1 WHERE a IN ('aaa', 'bbb', 'ccc'); 26 } 27} {} 28do_test in4-1.3 { 29 execsql { 30 INSERT INTO t1 VALUES('aaa', 1); 31 INSERT INTO t1 VALUES('ddd', 2); 32 INSERT INTO t1 VALUES('ccc', 3); 33 INSERT INTO t1 VALUES('eee', 4); 34 SELECT b FROM t1 WHERE a IN ('aaa', 'bbb', 'ccc'); 35 } 36} {1 3} 37do_test in4-1.4 { 38 execsql { 39 SELECT a FROM t1 WHERE rowid IN (1, 3); 40 } 41} {aaa ccc} 42do_test in4-1.5 { 43 execsql { 44 SELECT a FROM t1 WHERE rowid IN (); 45 } 46} {} 47do_test in4-1.6 { 48 execsql { 49 SELECT a FROM t1 WHERE a IN ('ddd'); 50 } 51} {ddd} 52 53do_test in4-2.1 { 54 execsql { 55 CREATE TABLE t2(a INTEGER PRIMARY KEY, b TEXT); 56 INSERT INTO t2 VALUES(-1, '-one'); 57 INSERT INTO t2 VALUES(0, 'zero'); 58 INSERT INTO t2 VALUES(1, 'one'); 59 INSERT INTO t2 VALUES(2, 'two'); 60 INSERT INTO t2 VALUES(3, 'three'); 61 } 62} {} 63 64do_test in4-2.2 { 65 execsql { SELECT b FROM t2 WHERE a IN (0, 2) } 66} {zero two} 67 68do_test in4-2.3 { 69 execsql { SELECT b FROM t2 WHERE a IN (2, 0) } 70} {zero two} 71 72do_test in4-2.4 { 73 execsql { SELECT b FROM t2 WHERE a IN (2, -1) } 74} {-one two} 75 76do_test in4-2.5 { 77 execsql { SELECT b FROM t2 WHERE a IN (NULL, 3) } 78} {three} 79 80do_test in4-2.6 { 81 execsql { SELECT b FROM t2 WHERE a IN (1.0, 2.1) } 82} {one} 83 84do_test in4-2.7 { 85 execsql { SELECT b FROM t2 WHERE a IN ('1', '2') } 86} {one two} 87 88do_test in4-2.8 { 89 execsql { SELECT b FROM t2 WHERE a IN ('', '0.0.0', '2') } 90} {two} 91 92# The following block of tests test expressions of the form: 93# 94# <expr> IN () 95# 96# i.e. IN expressions with a literal empty set. 97# 98# This has led to crashes on more than one occasion. Test case in4-3.2 99# was added in reponse to a bug reported on the mailing list on 11/7/2008. 100# See also tickets #3602 and #185. 101# 102do_test in4-3.1 { 103 execsql { 104 DROP TABLE IF EXISTS t1; 105 DROP TABLE IF EXISTS t2; 106 CREATE TABLE t1(x, id); 107 CREATE TABLE t2(x, id); 108 INSERT INTO t1 VALUES(NULL, NULL); 109 INSERT INTO t1 VALUES(0, NULL); 110 INSERT INTO t1 VALUES(1, 3); 111 INSERT INTO t1 VALUES(2, 4); 112 INSERT INTO t1 VALUES(3, 5); 113 INSERT INTO t1 VALUES(4, 6); 114 INSERT INTO t2 VALUES(0, NULL); 115 INSERT INTO t2 VALUES(4, 1); 116 INSERT INTO t2 VALUES(NULL, 1); 117 INSERT INTO t2 VALUES(NULL, NULL); 118 } 119} {} 120do_test in4-3.2 { 121 execsql { 122 SELECT x FROM t1 WHERE id IN () AND x IN (SELECT x FROM t2 WHERE id=1) 123 } 124} {} 125do_test in4-3.3 { 126 execsql { 127 CREATE TABLE t3(x, y, z); 128 CREATE INDEX t3i1 ON t3(x, y); 129 INSERT INTO t3 VALUES(1, 1, 1); 130 INSERT INTO t3 VALUES(10, 10, 10); 131 } 132 execsql { SELECT * FROM t3 WHERE x IN () } 133} {} 134do_test in4-3.4 { 135 execsql { SELECT * FROM t3 WHERE x = 10 AND y IN () } 136} {} 137do_test in4-3.5 { 138 execsql { SELECT * FROM t3 WHERE x IN () AND y = 10 } 139} {} 140do_test in4-3.6 { 141 execsql { SELECT * FROM t3 WHERE x IN () OR x = 10 } 142} {10 10 10} 143do_test in4-3.7 { 144 execsql { SELECT * FROM t3 WHERE y IN () } 145} {} 146do_test in4-3.8 { 147 execsql { SELECT x IN() AS a FROM t3 WHERE a } 148} {} 149do_test in4-3.9 { 150 execsql { SELECT x IN() AS a FROM t3 WHERE NOT a } 151} {0 0} 152do_test in4-3.10 { 153 execsql { SELECT * FROM t3 WHERE oid IN () } 154} {} 155do_test in4-3.11 { 156 execsql { SELECT * FROM t3 WHERE x IN (1, 2) OR y IN ()} 157} {1 1 1} 158do_test in4-3.12 { 159 execsql { SELECT * FROM t3 WHERE x IN (1, 2) AND y IN ()} 160} {} 161 162# Tests for "... IN (?)" and "... NOT IN (?)". In other words, tests 163# for when the RHS of IN is a single expression. This should work the 164# same as the == and <> operators. 165# 166do_execsql_test in4-3.21 { 167 SELECT * FROM t3 WHERE x=10 AND y IN (10); 168} {10 10 10} 169do_execsql_test in4-3.22 { 170 SELECT * FROM t3 WHERE x IN (10) AND y=10; 171} {10 10 10} 172do_execsql_test in4-3.23 { 173 SELECT * FROM t3 WHERE x IN (10) AND y IN (10); 174} {10 10 10} 175do_execsql_test in4-3.24 { 176 SELECT * FROM t3 WHERE x=1 AND y NOT IN (10); 177} {1 1 1} 178do_execsql_test in4-3.25 { 179 SELECT * FROM t3 WHERE x NOT IN (10) AND y=1; 180} {1 1 1} 181do_execsql_test in4-3.26 { 182 SELECT * FROM t3 WHERE x NOT IN (10) AND y NOT IN (10); 183} {1 1 1} 184 185# The query planner recognizes that "x IN (?)" only generates a 186# single match and can use this information to optimize-out ORDER BY 187# clauses. 188# 189do_execsql_test in4-3.31 { 190 DROP INDEX t3i1; 191 CREATE UNIQUE INDEX t3xy ON t3(x,y); 192 193 SELECT *, '|' FROM t3 A, t3 B 194 WHERE A.x=10 AND A.y IN (10) 195 AND B.x=1 AND B.y IN (1); 196} {10 10 10 1 1 1 |} 197do_execsql_test in4-3.32 { 198 EXPLAIN QUERY PLAN 199 SELECT *, '|' FROM t3 A, t3 B 200 WHERE A.x=10 AND A.y IN (10) 201 AND B.x=1 AND B.y IN (1); 202} {~/B-TREE/} ;# No separate sorting pass 203do_execsql_test in4-3.33 { 204 SELECT *, '|' FROM t3 A, t3 B 205 WHERE A.x IN (10) AND A.y=10 206 AND B.x IN (1) AND B.y=1; 207} {10 10 10 1 1 1 |} 208do_execsql_test in4-3.34 { 209 EXPLAIN QUERY PLAN 210 SELECT *, '|' FROM t3 A, t3 B 211 WHERE A.x IN (10) AND A.y=10 212 AND B.x IN (1) AND B.y=1; 213} {~/B-TREE/} ;# No separate sorting pass 214 215# An expression of the form "x IN (?,?)" creates an ephemeral table to 216# hold the list of values on the RHS. But "x IN (?)" does not create 217# an ephemeral table. 218# 219do_execsql_test in4-3.41 { 220 SELECT * FROM t3 WHERE x IN (10,11); 221} {10 10 10} 222do_execsql_test in4-3.42 { 223 EXPLAIN 224 SELECT * FROM t3 WHERE x IN (10,11); 225} {/OpenEphemeral/} 226do_execsql_test in4-3.43 { 227 SELECT * FROM t3 WHERE x IN (10); 228} {10 10 10} 229do_execsql_test in4-3.44 { 230 EXPLAIN 231 SELECT * FROM t3 WHERE x IN (10); 232} {~/OpenEphemeral/} 233do_execsql_test in4-3.45 { 234 SELECT * FROM t3 WHERE x NOT IN (10,11,99999); 235} {1 1 1} 236do_execsql_test in4-3.46 { 237 EXPLAIN 238 SELECT * FROM t3 WHERE x NOT IN (10,11,99999); 239} {/OpenEphemeral/} 240do_execsql_test in4-3.47 { 241 SELECT * FROM t3 WHERE x NOT IN (10); 242} {1 1 1} 243do_execsql_test in4-3.48 { 244 EXPLAIN 245 SELECT * FROM t3 WHERE x NOT IN (10); 246} {~/OpenEphemeral/} 247 248# Make sure that when "x IN (?)" is converted into "x==?" that collating 249# sequence and affinity computations do not get messed up. 250# 251do_execsql_test in4-4.1 { 252 CREATE TABLE t4a(a TEXT, b TEXT COLLATE nocase, c); 253 INSERT INTO t4a VALUES('ABC','abc',1); 254 INSERT INTO t4a VALUES('def','xyz',2); 255 INSERT INTO t4a VALUES('ghi','ghi',3); 256 SELECT c FROM t4a WHERE a=b ORDER BY c; 257} {3} 258do_execsql_test in4-4.2 { 259 SELECT c FROM t4a WHERE b=a ORDER BY c; 260} {1 3} 261do_execsql_test in4-4.3 { 262 SELECT c FROM t4a WHERE (a||'')=b ORDER BY c; 263} {1 3} 264do_execsql_test in4-4.4 { 265 SELECT c FROM t4a WHERE (a||'')=(b||'') ORDER BY c; 266} {3} 267do_execsql_test in4-4.5 { 268 SELECT c FROM t4a WHERE a IN (b) ORDER BY c; 269} {3} 270do_execsql_test in4-4.6 { 271 SELECT c FROM t4a WHERE (a||'') IN (b) ORDER BY c; 272} {3} 273 274 275do_execsql_test in4-4.11 { 276 CREATE TABLE t4b(a TEXT, b NUMERIC, c); 277 INSERT INTO t4b VALUES('1.0',1,4); 278 SELECT c FROM t4b WHERE a=b; 279} {4} 280do_execsql_test in4-4.12 { 281 SELECT c FROM t4b WHERE b=a; 282} {4} 283do_execsql_test in4-4.13 { 284 SELECT c FROM t4b WHERE +a=b; 285} {4} 286do_execsql_test in4-4.14 { 287 SELECT c FROM t4b WHERE a=+b; 288} {} 289do_execsql_test in4-4.15 { 290 SELECT c FROM t4b WHERE +b=a; 291} {} 292do_execsql_test in4-4.16 { 293 SELECT c FROM t4b WHERE b=+a; 294} {4} 295do_execsql_test in4-4.17 { 296 SELECT c FROM t4b WHERE a IN (b); 297} {} 298do_execsql_test in4-4.18 { 299 SELECT c FROM t4b WHERE b IN (a); 300} {4} 301do_execsql_test in4-4.19 { 302 SELECT c FROM t4b WHERE +b IN (a); 303} {} 304 305do_execsql_test in4-5.1 { 306 CREATE TABLE t5(c INTEGER PRIMARY KEY, d TEXT COLLATE nocase); 307 INSERT INTO t5 VALUES(17, 'fuzz'); 308 SELECT 1 FROM t5 WHERE 'fuzz' IN (d); -- match 309 SELECT 2 FROM t5 WHERE 'FUZZ' IN (d); -- no match 310 SELECT 3 FROM t5 WHERE d IN ('fuzz'); -- match 311 SELECT 4 FROM t5 WHERE d IN ('FUZZ'); -- match 312} {1 3 4} 313 314# An expression of the form "x IN (y)" can be used as "x=y" by the 315# query planner when computing transitive constraints or to run the 316# query using an index on y. 317# 318do_execsql_test in4-6.1 { 319 CREATE TABLE t6a(a INTEGER PRIMARY KEY, b); 320 INSERT INTO t6a VALUES(1,2),(3,4),(5,6); 321 CREATE TABLE t6b(c INTEGER PRIMARY KEY, d); 322 INSERT INTO t6b VALUES(4,44),(5,55),(6,66); 323 324 SELECT * FROM t6a, t6b WHERE a=3 AND b IN (c); 325} {3 4 4 44} 326do_execsql_test in4-6.1-eqp { 327 EXPLAIN QUERY PLAN 328 SELECT * FROM t6a, t6b WHERE a=3 AND b IN (c); 329} {~/SCAN/} 330do_execsql_test in4-6.2 { 331 SELECT * FROM t6a, t6b WHERE a=3 AND c IN (b); 332} {3 4 4 44} 333do_execsql_test in4-6.2-eqp { 334 EXPLAIN QUERY PLAN 335 SELECT * FROM t6a, t6b WHERE a=3 AND c IN (b); 336} {~/SCAN/} 337 338 339finish_test 340