xref: /sqlite-3.40.0/test/in4.test (revision 5d742e39)
141a05b7bSdanielk1977# 2008 September 1
241a05b7bSdanielk1977#
341a05b7bSdanielk1977# The author disclaims copyright to this source code.  In place of
441a05b7bSdanielk1977# a legal notice, here is a blessing:
541a05b7bSdanielk1977#
641a05b7bSdanielk1977#    May you do good and not evil.
741a05b7bSdanielk1977#    May you find forgiveness for yourself and forgive others.
841a05b7bSdanielk1977#    May you share freely, never taking more than you give.
941a05b7bSdanielk1977#
1041a05b7bSdanielk1977#***********************************************************************
1141a05b7bSdanielk1977#
12dda70fe3Sdrh# $Id: in4.test,v 1.4 2009/06/05 17:09:12 drh Exp $
1341a05b7bSdanielk1977
1441a05b7bSdanielk1977set testdir [file dirname $argv0]
1541a05b7bSdanielk1977source $testdir/tester.tcl
1674ebaadcSdanset testprefix in4
1741a05b7bSdanielk1977
1841a05b7bSdanielk1977do_test in4-1.1 {
1941a05b7bSdanielk1977  execsql {
2041a05b7bSdanielk1977    CREATE TABLE t1(a, b);
2141a05b7bSdanielk1977    CREATE INDEX i1 ON t1(a);
2241a05b7bSdanielk1977  }
2341a05b7bSdanielk1977} {}
2441a05b7bSdanielk1977do_test in4-1.2 {
2541a05b7bSdanielk1977  execsql {
2641a05b7bSdanielk1977    SELECT * FROM t1 WHERE a IN ('aaa', 'bbb', 'ccc');
2741a05b7bSdanielk1977  }
2841a05b7bSdanielk1977} {}
2941a05b7bSdanielk1977do_test in4-1.3 {
3041a05b7bSdanielk1977  execsql {
3141a05b7bSdanielk1977    INSERT INTO t1 VALUES('aaa', 1);
3241a05b7bSdanielk1977    INSERT INTO t1 VALUES('ddd', 2);
3341a05b7bSdanielk1977    INSERT INTO t1 VALUES('ccc', 3);
3441a05b7bSdanielk1977    INSERT INTO t1 VALUES('eee', 4);
3541a05b7bSdanielk1977    SELECT b FROM t1 WHERE a IN ('aaa', 'bbb', 'ccc');
3641a05b7bSdanielk1977  }
3741a05b7bSdanielk1977} {1 3}
3841a05b7bSdanielk1977do_test in4-1.4 {
3941a05b7bSdanielk1977  execsql {
4041a05b7bSdanielk1977    SELECT a FROM t1 WHERE rowid IN (1, 3);
4141a05b7bSdanielk1977  }
4241a05b7bSdanielk1977} {aaa ccc}
4341a05b7bSdanielk1977do_test in4-1.5 {
4441a05b7bSdanielk1977  execsql {
4541a05b7bSdanielk1977    SELECT a FROM t1 WHERE rowid IN ();
4641a05b7bSdanielk1977  }
4741a05b7bSdanielk1977} {}
4841a05b7bSdanielk1977do_test in4-1.6 {
4941a05b7bSdanielk1977  execsql {
5041a05b7bSdanielk1977    SELECT a FROM t1 WHERE a IN ('ddd');
5141a05b7bSdanielk1977  }
5241a05b7bSdanielk1977} {ddd}
5341a05b7bSdanielk1977
5441a05b7bSdanielk1977do_test in4-2.1 {
5541a05b7bSdanielk1977  execsql {
5641a05b7bSdanielk1977    CREATE TABLE t2(a INTEGER PRIMARY KEY, b TEXT);
5741a05b7bSdanielk1977    INSERT INTO t2 VALUES(-1, '-one');
5841a05b7bSdanielk1977    INSERT INTO t2 VALUES(0, 'zero');
5941a05b7bSdanielk1977    INSERT INTO t2 VALUES(1, 'one');
6041a05b7bSdanielk1977    INSERT INTO t2 VALUES(2, 'two');
6141a05b7bSdanielk1977    INSERT INTO t2 VALUES(3, 'three');
6241a05b7bSdanielk1977  }
6341a05b7bSdanielk1977} {}
6441a05b7bSdanielk1977
6541a05b7bSdanielk1977do_test in4-2.2 {
6641a05b7bSdanielk1977  execsql { SELECT b FROM t2 WHERE a IN (0, 2) }
6741a05b7bSdanielk1977} {zero two}
6841a05b7bSdanielk1977
6941a05b7bSdanielk1977do_test in4-2.3 {
7041a05b7bSdanielk1977  execsql { SELECT b FROM t2 WHERE a IN (2, 0) }
7141a05b7bSdanielk1977} {zero two}
7241a05b7bSdanielk1977
7341a05b7bSdanielk1977do_test in4-2.4 {
7441a05b7bSdanielk1977  execsql { SELECT b FROM t2 WHERE a IN (2, -1) }
7541a05b7bSdanielk1977} {-one two}
7641a05b7bSdanielk1977
7741a05b7bSdanielk1977do_test in4-2.5 {
7841a05b7bSdanielk1977  execsql { SELECT b FROM t2 WHERE a IN (NULL, 3) }
7941a05b7bSdanielk1977} {three}
8041a05b7bSdanielk1977
8141a05b7bSdanielk1977do_test in4-2.6 {
8241a05b7bSdanielk1977  execsql { SELECT b FROM t2 WHERE a IN (1.0, 2.1) }
8341a05b7bSdanielk1977} {one}
8441a05b7bSdanielk1977
8541a05b7bSdanielk1977do_test in4-2.7 {
8641a05b7bSdanielk1977  execsql { SELECT b FROM t2 WHERE a IN ('1', '2') }
8741a05b7bSdanielk1977} {one two}
8841a05b7bSdanielk1977
8941a05b7bSdanielk1977do_test in4-2.8 {
9041a05b7bSdanielk1977  execsql { SELECT b FROM t2 WHERE a IN ('', '0.0.0', '2') }
9141a05b7bSdanielk1977} {two}
9241a05b7bSdanielk1977
9325f42fe7Sdanielk1977# The following block of tests test expressions of the form:
9425f42fe7Sdanielk1977#
9525f42fe7Sdanielk1977#    <expr> IN ()
9625f42fe7Sdanielk1977#
9725f42fe7Sdanielk1977# i.e. IN expressions with a literal empty set.
9825f42fe7Sdanielk1977#
9925f42fe7Sdanielk1977# This has led to crashes on more than one occasion. Test case in4-3.2
10025f42fe7Sdanielk1977# was added in reponse to a bug reported on the mailing list on 11/7/2008.
10125f42fe7Sdanielk1977# See also tickets #3602 and #185.
10225f42fe7Sdanielk1977#
103481e9f20Sshanedo_test in4-3.1 {
104481e9f20Sshane  execsql {
105481e9f20Sshane    DROP TABLE IF EXISTS t1;
106481e9f20Sshane    DROP TABLE IF EXISTS t2;
107481e9f20Sshane    CREATE TABLE t1(x, id);
108481e9f20Sshane    CREATE TABLE t2(x, id);
109481e9f20Sshane    INSERT INTO t1 VALUES(NULL, NULL);
110481e9f20Sshane    INSERT INTO t1 VALUES(0, NULL);
111481e9f20Sshane    INSERT INTO t1 VALUES(1, 3);
112481e9f20Sshane    INSERT INTO t1 VALUES(2, 4);
113481e9f20Sshane    INSERT INTO t1 VALUES(3, 5);
114481e9f20Sshane    INSERT INTO t1 VALUES(4, 6);
115481e9f20Sshane    INSERT INTO t2 VALUES(0, NULL);
116481e9f20Sshane    INSERT INTO t2 VALUES(4, 1);
117481e9f20Sshane    INSERT INTO t2 VALUES(NULL, 1);
118481e9f20Sshane    INSERT INTO t2 VALUES(NULL, NULL);
119481e9f20Sshane  }
120481e9f20Sshane} {}
121481e9f20Sshanedo_test in4-3.2 {
122481e9f20Sshane  execsql {
123481e9f20Sshane    SELECT x FROM t1 WHERE id IN () AND x IN (SELECT x FROM t2 WHERE id=1)
124481e9f20Sshane  }
125481e9f20Sshane} {}
12625f42fe7Sdanielk1977do_test in4-3.3 {
12725f42fe7Sdanielk1977  execsql {
12825f42fe7Sdanielk1977    CREATE TABLE t3(x, y, z);
12925f42fe7Sdanielk1977    CREATE INDEX t3i1 ON t3(x, y);
13025f42fe7Sdanielk1977    INSERT INTO t3 VALUES(1, 1, 1);
13125f42fe7Sdanielk1977    INSERT INTO t3 VALUES(10, 10, 10);
13225f42fe7Sdanielk1977  }
13325f42fe7Sdanielk1977  execsql { SELECT * FROM t3 WHERE x IN () }
13425f42fe7Sdanielk1977} {}
13525f42fe7Sdanielk1977do_test in4-3.4 {
13625f42fe7Sdanielk1977  execsql { SELECT * FROM t3 WHERE x = 10 AND y IN () }
13725f42fe7Sdanielk1977} {}
13825f42fe7Sdanielk1977do_test in4-3.5 {
13925f42fe7Sdanielk1977  execsql { SELECT * FROM t3 WHERE x IN () AND y = 10 }
14025f42fe7Sdanielk1977} {}
14125f42fe7Sdanielk1977do_test in4-3.6 {
14225f42fe7Sdanielk1977  execsql { SELECT * FROM t3 WHERE x IN () OR x = 10 }
14325f42fe7Sdanielk1977} {10 10 10}
14425f42fe7Sdanielk1977do_test in4-3.7 {
14525f42fe7Sdanielk1977  execsql { SELECT * FROM t3 WHERE y IN () }
14625f42fe7Sdanielk1977} {}
14725f42fe7Sdanielk1977do_test in4-3.8 {
14825f42fe7Sdanielk1977  execsql { SELECT x IN() AS a FROM t3 WHERE a }
14925f42fe7Sdanielk1977} {}
15025f42fe7Sdanielk1977do_test in4-3.9 {
15125f42fe7Sdanielk1977  execsql { SELECT x IN() AS a FROM t3 WHERE NOT a }
15225f42fe7Sdanielk1977} {0 0}
15325f42fe7Sdanielk1977do_test in4-3.10 {
15425f42fe7Sdanielk1977  execsql { SELECT * FROM t3 WHERE oid IN () }
15525f42fe7Sdanielk1977} {}
15625f42fe7Sdanielk1977do_test in4-3.11 {
15725f42fe7Sdanielk1977  execsql { SELECT * FROM t3 WHERE x IN (1, 2) OR y IN ()}
15825f42fe7Sdanielk1977} {1 1 1}
15925f42fe7Sdanielk1977do_test in4-3.12 {
16025f42fe7Sdanielk1977  execsql { SELECT * FROM t3 WHERE x IN (1, 2) AND y IN ()}
16125f42fe7Sdanielk1977} {}
162481e9f20Sshane
1632b59b3a4Sdrh# Tests for "... IN (?)" and "... NOT IN (?)".  In other words, tests
1642b59b3a4Sdrh# for when the RHS of IN is a single expression.  This should work the
1652b59b3a4Sdrh# same as the == and <> operators.
1662b59b3a4Sdrh#
1672b59b3a4Sdrhdo_execsql_test in4-3.21 {
1682b59b3a4Sdrh  SELECT * FROM t3 WHERE x=10 AND y IN (10);
1692b59b3a4Sdrh} {10 10 10}
1702b59b3a4Sdrhdo_execsql_test in4-3.22 {
1712b59b3a4Sdrh  SELECT * FROM t3 WHERE x IN (10) AND y=10;
1722b59b3a4Sdrh} {10 10 10}
1732b59b3a4Sdrhdo_execsql_test in4-3.23 {
1742b59b3a4Sdrh  SELECT * FROM t3 WHERE x IN (10) AND y IN (10);
1752b59b3a4Sdrh} {10 10 10}
1762b59b3a4Sdrhdo_execsql_test in4-3.24 {
1772b59b3a4Sdrh  SELECT * FROM t3 WHERE x=1 AND y NOT IN (10);
1782b59b3a4Sdrh} {1 1 1}
1792b59b3a4Sdrhdo_execsql_test in4-3.25 {
1802b59b3a4Sdrh  SELECT * FROM t3 WHERE x  NOT IN (10) AND y=1;
1812b59b3a4Sdrh} {1 1 1}
1822b59b3a4Sdrhdo_execsql_test in4-3.26 {
1832b59b3a4Sdrh  SELECT * FROM t3 WHERE x NOT IN (10) AND y NOT IN (10);
1842b59b3a4Sdrh} {1 1 1}
1852b59b3a4Sdrh
1862b59b3a4Sdrh# The query planner recognizes that "x IN (?)" only generates a
1872b59b3a4Sdrh# single match and can use this information to optimize-out ORDER BY
1882b59b3a4Sdrh# clauses.
1892b59b3a4Sdrh#
1902b59b3a4Sdrhdo_execsql_test in4-3.31 {
1912b59b3a4Sdrh  DROP INDEX t3i1;
1922b59b3a4Sdrh  CREATE UNIQUE INDEX t3xy ON t3(x,y);
1932b59b3a4Sdrh
1942b59b3a4Sdrh  SELECT *, '|' FROM t3 A, t3 B
1952b59b3a4Sdrh   WHERE A.x=10 AND A.y IN (10)
1962b59b3a4Sdrh     AND B.x=1 AND B.y IN (1);
1972b59b3a4Sdrh} {10 10 10 1 1 1 |}
1982b59b3a4Sdrhdo_execsql_test in4-3.32 {
1992b59b3a4Sdrh  EXPLAIN QUERY PLAN
2002b59b3a4Sdrh  SELECT *, '|' FROM t3 A, t3 B
2012b59b3a4Sdrh   WHERE A.x=10 AND A.y IN (10)
2022b59b3a4Sdrh     AND B.x=1 AND B.y IN (1);
2032b59b3a4Sdrh} {~/B-TREE/}  ;# No separate sorting pass
2042b59b3a4Sdrhdo_execsql_test in4-3.33 {
2052b59b3a4Sdrh  SELECT *, '|' FROM t3 A, t3 B
2062b59b3a4Sdrh   WHERE A.x IN (10) AND A.y=10
2072b59b3a4Sdrh     AND B.x IN (1) AND B.y=1;
2082b59b3a4Sdrh} {10 10 10 1 1 1 |}
2092b59b3a4Sdrhdo_execsql_test in4-3.34 {
2102b59b3a4Sdrh  EXPLAIN QUERY PLAN
2112b59b3a4Sdrh  SELECT *, '|' FROM t3 A, t3 B
2122b59b3a4Sdrh   WHERE A.x IN (10) AND A.y=10
2132b59b3a4Sdrh     AND B.x IN (1) AND B.y=1;
2142b59b3a4Sdrh} {~/B-TREE/}  ;# No separate sorting pass
2152b59b3a4Sdrh
2162b59b3a4Sdrh# An expression of the form "x IN (?,?)" creates an ephemeral table to
2172b59b3a4Sdrh# hold the list of values on the RHS.  But "x IN (?)" does not create
2182b59b3a4Sdrh# an ephemeral table.
2192b59b3a4Sdrh#
2202b59b3a4Sdrhdo_execsql_test in4-3.41 {
2212b59b3a4Sdrh  SELECT * FROM t3 WHERE x IN (10,11);
2222b59b3a4Sdrh} {10 10 10}
2232b59b3a4Sdrhdo_execsql_test in4-3.42 {
2242b59b3a4Sdrh  EXPLAIN
2252b59b3a4Sdrh  SELECT * FROM t3 WHERE x IN (10,11);
2262b59b3a4Sdrh} {/OpenEphemeral/}
2272b59b3a4Sdrhdo_execsql_test in4-3.43 {
2282b59b3a4Sdrh  SELECT * FROM t3 WHERE x IN (10);
2292b59b3a4Sdrh} {10 10 10}
230790b37a2Sdrh
231790b37a2Sdrh# This test would verify that the "X IN (Y)" -> "X==Y" optimization
232790b37a2Sdrh# was working.  But we have now taken that optimization out.
233790b37a2Sdrh#do_execsql_test in4-3.44 {
234790b37a2Sdrh#  EXPLAIN
235790b37a2Sdrh#  SELECT * FROM t3 WHERE x IN (10);
236790b37a2Sdrh#} {~/OpenEphemeral/}
2372b59b3a4Sdrhdo_execsql_test in4-3.45 {
238bb53ecb1Sdrh  SELECT * FROM t3 WHERE x NOT IN (10,11,99999);
2392b59b3a4Sdrh} {1 1 1}
2402b59b3a4Sdrhdo_execsql_test in4-3.46 {
2412b59b3a4Sdrh  EXPLAIN
242bb53ecb1Sdrh  SELECT * FROM t3 WHERE x NOT IN (10,11,99999);
2432b59b3a4Sdrh} {/OpenEphemeral/}
2442b59b3a4Sdrhdo_execsql_test in4-3.47 {
2452b59b3a4Sdrh  SELECT * FROM t3 WHERE x NOT IN (10);
2462b59b3a4Sdrh} {1 1 1}
2472b59b3a4Sdrhdo_execsql_test in4-3.48 {
2482b59b3a4Sdrh  EXPLAIN
2492b59b3a4Sdrh  SELECT * FROM t3 WHERE x NOT IN (10);
2502b59b3a4Sdrh} {~/OpenEphemeral/}
2512b59b3a4Sdrh
2520a8d1426Sdrh# Make sure that when "x IN (?)" is converted into "x==?" that collating
2530a8d1426Sdrh# sequence and affinity computations do not get messed up.
2540a8d1426Sdrh#
2550a8d1426Sdrhdo_execsql_test in4-4.1 {
2560a8d1426Sdrh  CREATE TABLE t4a(a TEXT, b TEXT COLLATE nocase, c);
2570a8d1426Sdrh  INSERT INTO t4a VALUES('ABC','abc',1);
2580a8d1426Sdrh  INSERT INTO t4a VALUES('def','xyz',2);
2590a8d1426Sdrh  INSERT INTO t4a VALUES('ghi','ghi',3);
2600a8d1426Sdrh  SELECT c FROM t4a WHERE a=b ORDER BY c;
2610a8d1426Sdrh} {3}
2620a8d1426Sdrhdo_execsql_test in4-4.2 {
2630a8d1426Sdrh  SELECT c FROM t4a WHERE b=a ORDER BY c;
2640a8d1426Sdrh} {1 3}
2650a8d1426Sdrhdo_execsql_test in4-4.3 {
2660a8d1426Sdrh  SELECT c FROM t4a WHERE (a||'')=b ORDER BY c;
2670a8d1426Sdrh} {1 3}
2680a8d1426Sdrhdo_execsql_test in4-4.4 {
2690a8d1426Sdrh  SELECT c FROM t4a WHERE (a||'')=(b||'') ORDER BY c;
2700a8d1426Sdrh} {3}
2710a8d1426Sdrhdo_execsql_test in4-4.5 {
2720a8d1426Sdrh  SELECT c FROM t4a WHERE a IN (b) ORDER BY c;
2730a8d1426Sdrh} {3}
2740a8d1426Sdrhdo_execsql_test in4-4.6 {
2750a8d1426Sdrh  SELECT c FROM t4a WHERE (a||'') IN (b) ORDER BY c;
2760a8d1426Sdrh} {3}
2770a8d1426Sdrh
2780a8d1426Sdrh
2790a8d1426Sdrhdo_execsql_test in4-4.11 {
2800a8d1426Sdrh  CREATE TABLE t4b(a TEXT, b NUMERIC, c);
2810a8d1426Sdrh  INSERT INTO t4b VALUES('1.0',1,4);
2820a8d1426Sdrh  SELECT c FROM t4b WHERE a=b;
2830a8d1426Sdrh} {4}
2840a8d1426Sdrhdo_execsql_test in4-4.12 {
2850a8d1426Sdrh  SELECT c FROM t4b WHERE b=a;
2860a8d1426Sdrh} {4}
2870a8d1426Sdrhdo_execsql_test in4-4.13 {
2880a8d1426Sdrh  SELECT c FROM t4b WHERE +a=b;
2890a8d1426Sdrh} {4}
2900a8d1426Sdrhdo_execsql_test in4-4.14 {
2910a8d1426Sdrh  SELECT c FROM t4b WHERE a=+b;
2920a8d1426Sdrh} {}
2930a8d1426Sdrhdo_execsql_test in4-4.15 {
2940a8d1426Sdrh  SELECT c FROM t4b WHERE +b=a;
2950a8d1426Sdrh} {}
2960a8d1426Sdrhdo_execsql_test in4-4.16 {
2970a8d1426Sdrh  SELECT c FROM t4b WHERE b=+a;
2980a8d1426Sdrh} {4}
2990a8d1426Sdrhdo_execsql_test in4-4.17 {
3000a8d1426Sdrh  SELECT c FROM t4b WHERE a IN (b);
3010a8d1426Sdrh} {}
3020a8d1426Sdrhdo_execsql_test in4-4.18 {
3030a8d1426Sdrh  SELECT c FROM t4b WHERE b IN (a);
3040a8d1426Sdrh} {4}
3050a8d1426Sdrhdo_execsql_test in4-4.19 {
3060a8d1426Sdrh  SELECT c FROM t4b WHERE +b IN (a);
3070a8d1426Sdrh} {}
3080a8d1426Sdrh
309fbb24d10Sdrhdo_execsql_test in4-5.1 {
310fbb24d10Sdrh  CREATE TABLE t5(c INTEGER PRIMARY KEY, d TEXT COLLATE nocase);
311fbb24d10Sdrh  INSERT INTO t5 VALUES(17, 'fuzz');
312fbb24d10Sdrh  SELECT 1 FROM t5 WHERE 'fuzz' IN (d);  -- match
313fbb24d10Sdrh  SELECT 2 FROM t5 WHERE 'FUZZ' IN (d);  -- no match
314fbb24d10Sdrh  SELECT 3 FROM t5 WHERE d IN ('fuzz');  -- match
315fbb24d10Sdrh  SELECT 4 FROM t5 WHERE d IN ('FUZZ');  -- match
316fbb24d10Sdrh} {1 3 4}
3170a8d1426Sdrh
318fbb24d10Sdrh# An expression of the form "x IN (y)" can be used as "x=y" by the
319fbb24d10Sdrh# query planner when computing transitive constraints or to run the
320fbb24d10Sdrh# query using an index on y.
321fbb24d10Sdrh#
322fbb24d10Sdrhdo_execsql_test in4-6.1 {
323fbb24d10Sdrh  CREATE TABLE t6a(a INTEGER PRIMARY KEY, b);
324fbb24d10Sdrh  INSERT INTO t6a VALUES(1,2),(3,4),(5,6);
325fbb24d10Sdrh  CREATE TABLE t6b(c INTEGER PRIMARY KEY, d);
326fbb24d10Sdrh  INSERT INTO t6b VALUES(4,44),(5,55),(6,66);
3270a8d1426Sdrh
328fbb24d10Sdrh  SELECT * FROM t6a, t6b WHERE a=3 AND b IN (c);
329fbb24d10Sdrh} {3 4 4 44}
330fbb24d10Sdrhdo_execsql_test in4-6.1-eqp {
331fbb24d10Sdrh  EXPLAIN QUERY PLAN
332fbb24d10Sdrh  SELECT * FROM t6a, t6b WHERE a=3 AND b IN (c);
3338210233cSdrh} {~/SCAN t6a/}
334fbb24d10Sdrhdo_execsql_test in4-6.2 {
335fbb24d10Sdrh  SELECT * FROM t6a, t6b WHERE a=3 AND c IN (b);
336fbb24d10Sdrh} {3 4 4 44}
337fbb24d10Sdrhdo_execsql_test in4-6.2-eqp {
338fbb24d10Sdrh  EXPLAIN QUERY PLAN
339fbb24d10Sdrh  SELECT * FROM t6a, t6b WHERE a=3 AND c IN (b);
340fbb24d10Sdrh} {~/SCAN/}
3412b59b3a4Sdrh
34274ebaadcSdanreset_db
34374ebaadcSdando_execsql_test 7.0 {
34474ebaadcSdan  CREATE TABLE t1(a, b, c);
34574ebaadcSdan  CREATE TABLE t2(d, e);
34674ebaadcSdan  CREATE INDEX t1bc ON t1(c, b);
34774ebaadcSdan  INSERT INTO t2(e) VALUES(1);
34874ebaadcSdan  INSERT INTO t1 VALUES(NULL, NULL, NULL);
34974ebaadcSdan}
35074ebaadcSdan
35174ebaadcSdando_execsql_test 7.1 {
35274ebaadcSdan  SELECT * FROM t2 LEFT JOIN t1 ON c = d AND b IN (10,10,10);
35374ebaadcSdan} {{} 1 {} {} {}}
35474ebaadcSdan
3556f2180d2Sdrhifcapable rtree {
35674ebaadcSdan  reset_db
35774ebaadcSdan  do_execsql_test 7.2 {
35874ebaadcSdan    CREATE VIRTUAL TABLE t1 USING rtree(a, b, c);
35974ebaadcSdan    CREATE TABLE t2(d INTEGER, e INT);
36074ebaadcSdan    INSERT INTO t2(e) VALUES(1);
36174ebaadcSdan  }
36274ebaadcSdan
36374ebaadcSdan  do_execsql_test 7.3 {
36474ebaadcSdan    SELECT * FROM t2 LEFT JOIN t1 ON c IN (d) AND b IN (10,10,10);
36574ebaadcSdan  } {{} 1 {} {} {}}
3666f2180d2Sdrh}
3672b59b3a4Sdrh
368df1b52e7Sdan#-------------------------------------------------------------------------
369df1b52e7Sdanreset_db
370df1b52e7Sdando_execsql_test 8.0 {
371df1b52e7Sdan  CREATE TABLE t1(x INTEGER PRIMARY KEY, y);
372df1b52e7Sdan  CREATE UNIQUE INDEX t1y ON t1(y);
373df1b52e7Sdan  INSERT INTO t1 VALUES(111, 'AAA'),(222, 'BBB'),(333, 'CCC');
374df1b52e7Sdan  CREATE TABLE t2(z);
375df1b52e7Sdan  INSERT INTO t2 VALUES('BBB'),('AAA');
376df1b52e7Sdan  ANALYZE sqlite_schema;
377df1b52e7Sdan  INSERT INTO sqlite_stat1 VALUES('t1', 't1y','100 1');
378df1b52e7Sdan}
379df1b52e7Sdan
380df1b52e7Sdandb close
381df1b52e7Sdansqlite3 db test.db
382df1b52e7Sdan
383df1b52e7Sdando_execsql_test 8.1 {
384df1b52e7Sdan  SELECT t1.x FROM t2 CROSS JOIN t1 WHERE t2.z = t1.y;
385df1b52e7Sdan} {222 111}
386df1b52e7Sdan
387df1b52e7Sdando_execsql_test 8.2 {
388df1b52e7Sdan  SELECT t1.x FROM t2 CROSS JOIN t1 WHERE t2.z = t1.y AND +t1.x IN (111, 222);
389df1b52e7Sdan} {222 111}
390df1b52e7Sdan
391df1b52e7Sdando_execsql_test 8.3 {
392df1b52e7Sdan  SELECT t1.x FROM t2 CROSS JOIN t1 WHERE t2.z = t1.y AND t1.x IN (111, 222);
393df1b52e7Sdan} {222 111}
394df1b52e7Sdan
395eda790d2Sdrh# 2021-06-02 forum post https://sqlite.org/forum/forumpost/b4fcb8a598
396eda790d2Sdrh# OP_SeekScan changes from check-in 4a43430fd23f8835 on 2020-09-30 causes
397eda790d2Sdrh# performance regression.
398eda790d2Sdrh#
399eda790d2Sdrhreset_db
400eda790d2Sdrhdo_execsql_test 9.0 {
401eda790d2Sdrh  CREATE TABLE node(node_id INTEGER PRIMARY KEY);
402eda790d2Sdrh  CREATE TABLE edge(node_from INT, node_to INT);
403eda790d2Sdrh  CREATE TABLE sub_nodes(node_id INTEGER PRIMARY KEY);
404eda790d2Sdrh  CREATE INDEX edge_from_to ON edge(node_from,node_to);
405eda790d2Sdrh  CREATE INDEX edge_to_from ON edge(node_to,node_from);
406eda790d2Sdrh  ANALYZE;
407eda790d2Sdrh  DELETE FROM sqlite_stat1;
408eda790d2Sdrh  INSERT INTO sqlite_stat1 VALUES
409eda790d2Sdrh    ('sub_nodes',NULL,'1000000'),
410eda790d2Sdrh    ('edge','edge_to_from','20000000 2 2'),
411eda790d2Sdrh    ('edge','edge_from_to','20000000 2 2'),
412eda790d2Sdrh    ('node',NULL,'10000000');
413eda790d2Sdrh  ANALYZE sqlite_schema;
414eda790d2Sdrh} {}
415eda790d2Sdrhdo_eqp_test 9.1 {
416eda790d2SdrhSELECT count(*) FROM edge
417eda790d2Sdrh WHERE node_from IN sub_nodes AND node_to IN sub_nodes;
418eda790d2Sdrh} {
419eda790d2Sdrh  QUERY PLAN
420eda790d2Sdrh  |--SEARCH edge USING COVERING INDEX edge_to_from (node_to=?)
421eda790d2Sdrh  |--USING ROWID SEARCH ON TABLE sub_nodes FOR IN-OPERATOR
422eda790d2Sdrh  `--USING ROWID SEARCH ON TABLE sub_nodes FOR IN-OPERATOR
423eda790d2Sdrh}
424eda790d2Sdrh# ^^^^^ the key to the above is that the index should only use a single
425eda790d2Sdrh#       term (node_to=?), not two terms (node_to=? AND node_from=).
426eda790d2Sdrh
42799664398Sdrh# dbsqlfuzz case
42899664398Sdrh#
42999664398Sdrhreset_db
43099664398Sdrhdo_execsql_test 10.0 {
43199664398Sdrh  CREATE TABLE t1(a,b,c,d,PRIMARY KEY(a,b,c)) WITHOUT ROWID;
43299664398Sdrh  INSERT INTO t1(a,b,c,d) VALUES
43399664398Sdrh    (0,-2,2,3),
43499664398Sdrh    (0,2,3,4),
43599664398Sdrh    (0,5,8,10),
43699664398Sdrh    (1,7,11,13);
43799664398Sdrh  ANALYZE sqlite_schema;
43899664398Sdrh  INSERT INTO sqlite_stat1 VALUES('t1','t1','10 3 2 1');
43999664398Sdrh  ANALYZE sqlite_schema;
44099664398Sdrh  PRAGMA reverse_unordered_selects(1);
44199664398Sdrh  SELECT d FROM t1 WHERE 0=a AND b IN (-17,-4,-3,1,5,25,7798);
44299664398Sdrh} {10}
443eda790d2Sdrh
4440d08402fSdrh# 2021-06-13 dbsqlfuzz e41762333a4d6e90a49e628f488d0873b2dba4c5
4450d08402fSdrh# The opcode that preceeds OP_SeekScan is usually OP_IdxGT, but can
4460d08402fSdrh# sometimes be OP_IdxGE
4470d08402fSdrh#
4480d08402fSdrhreset_db
4490d08402fSdrhdo_execsql_test 11.0 {
4500d08402fSdrh  CREATE TABLE t1(a TEXT, b INT, c INT, d INT);
4510d08402fSdrh  INSERT INTO t1 VALUES('abc',123,4,5);
4520d08402fSdrh  INSERT INTO t1 VALUES('xyz',1,'abcdefxyz',99);
4530d08402fSdrh  CREATE INDEX t1abc ON t1(b,b,c);
4540d08402fSdrh  ANALYZE sqlite_schema;
4550d08402fSdrh  INSERT INTO sqlite_stat1 VALUES('t1','t1abc','10000 5 00 2003 10');
4560d08402fSdrh  ANALYZE sqlite_schema;
4570d08402fSdrh} {}
4580d08402fSdrhdo_execsql_test 11.1 {
4590d08402fSdrh  SELECT * FROM t1
4600d08402fSdrh   WHERE b IN (345, (SELECT 1 FROM t1
4610d08402fSdrh                      WHERE b IN (345 NOT GLOB 510)
4620d08402fSdrh                        AND c GLOB 'abc*xyz'))
4630d08402fSdrh     AND c BETWEEN 'abc' AND 'xyz';
4640d08402fSdrh} {xyz 1 abcdefxyz 99}
4650d08402fSdrhdo_execsql_test 11.2 {
4660d08402fSdrh  EXPLAIN SELECT * FROM t1
4670d08402fSdrh   WHERE b IN (345, (SELECT 1 FROM t1
4680d08402fSdrh                      WHERE b IN (345 NOT GLOB 510)
4690d08402fSdrh                        AND c GLOB 'abc*xyz'))
4700d08402fSdrh     AND c BETWEEN 'abc' AND 'xyz';
4710d08402fSdrh} {/ SeekScan /}
472df1b52e7Sdan
4734422b3a6Sdrh# 2021-06-25 ticket 6dcbfd11cf666e21
4744422b3a6Sdrh# Another problem with OP_SeekScan
4754422b3a6Sdrh#
4764422b3a6Sdrhreset_db
4774422b3a6Sdrhdo_execsql_test 12.0 {
4784422b3a6Sdrh  CREATE TABLE t1(a,b,c);
4794422b3a6Sdrh  CREATE INDEX t1abc ON t1(a,b,c);
4804422b3a6Sdrh  CREATE INDEX t1bca on t1(b,c,a);
4814422b3a6Sdrh  INSERT INTO t1 VALUES(56,1119,1115);
4824422b3a6Sdrh  INSERT INTO t1 VALUES(57,1147,1137);
4834422b3a6Sdrh  INSERT INTO t1 VALUES(100,1050,1023);
4844422b3a6Sdrh  INSERT INTO t1 VALUES(101,1050,1023);
4854422b3a6Sdrh  ANALYZE sqlite_schema;
4864422b3a6Sdrh  INSERT INTO sqlite_stat1 VALUES('t1','t1abc','358677 2 2 1');
4874422b3a6Sdrh  INSERT INTO sqlite_stat1 VALUES('t1','t1bca','358677 4 2 1');
4884422b3a6Sdrh  ANALYZE sqlite_schema;
4894422b3a6Sdrh  SELECT * FROM t1 NOT INDEXED
4904422b3a6Sdrh   WHERE (b = 1137 AND c IN (97, 98))
4914422b3a6Sdrh      OR (b = 1119 AND c IN (1115, 1023));
4924422b3a6Sdrh} {56 1119 1115}
4934422b3a6Sdrhdo_execsql_test 12.1 {
4944422b3a6Sdrh  SELECT * FROM t1
4954422b3a6Sdrh   WHERE (b = 1137 AND c IN (97, 98))
4964422b3a6Sdrh      OR (b = 1119 AND c IN (1115, 1023));
4974422b3a6Sdrh} {56 1119 1115}
4984422b3a6Sdrh
499*5d742e39Sdrh# 2021-11-02 ticket 5981a8c041a3c2f3
500*5d742e39Sdrh# Another OP_SeekScan problem.
501*5d742e39Sdrh#
502*5d742e39Sdrhreset_db
503*5d742e39Sdrhdo_execsql_test 13.0 {
504*5d742e39Sdrh  CREATE TABLE t1(id INTEGER PRIMARY KEY, a INT, b INT, c INT);
505*5d742e39Sdrh  INSERT INTO t1 VALUES(10,1,2,5);
506*5d742e39Sdrh  INSERT INTO t1 VALUES(20,1,3,5);
507*5d742e39Sdrh  INSERT INTO t1 VALUES(30,1,2,4);
508*5d742e39Sdrh  INSERT INTO t1 VALUES(40,1,3,4);
509*5d742e39Sdrh  ANALYZE sqlite_master;
510*5d742e39Sdrh  INSERT INTO sqlite_stat1 VALUES('t1','t1x','84000 3 2 1');
511*5d742e39Sdrh  CREATE INDEX t1x ON t1(a,b,c);
512*5d742e39Sdrh  PRAGMA writable_schema=RESET;
513*5d742e39Sdrh  SELECT * FROM t1
514*5d742e39Sdrh   WHERE a=1
515*5d742e39Sdrh     AND b IN (2,3)
516*5d742e39Sdrh     AND c BETWEEN 4 AND 5
517*5d742e39Sdrh   ORDER BY +id;
518*5d742e39Sdrh} {10 1 2 5 20 1 3 5 30 1 2 4 40 1 3 4}
519*5d742e39Sdrh
52041a05b7bSdanielk1977finish_test
521