xref: /sqlite-3.40.0/test/in3.test (revision de3e41e3)
19a96b668Sdanielk1977# 2007 November 29
29a96b668Sdanielk1977#
39a96b668Sdanielk1977# The author disclaims copyright to this source code.  In place of
49a96b668Sdanielk1977# a legal notice, here is a blessing:
59a96b668Sdanielk1977#
69a96b668Sdanielk1977#    May you do good and not evil.
79a96b668Sdanielk1977#    May you find forgiveness for yourself and forgive others.
89a96b668Sdanielk1977#    May you share freely, never taking more than you give.
99a96b668Sdanielk1977#
109a96b668Sdanielk1977#***********************************************************************
119a96b668Sdanielk1977# This file tests the optimisations made in November 2007 of expressions
129a96b668Sdanielk1977# of the following form:
139a96b668Sdanielk1977#
149a96b668Sdanielk1977#     <value> IN (SELECT <column> FROM <table>)
159a96b668Sdanielk1977#
16*de3e41e3Sdanielk1977# $Id: in3.test,v 1.5 2008/08/04 03:51:24 danielk1977 Exp $
179a96b668Sdanielk1977
189a96b668Sdanielk1977set testdir [file dirname $argv0]
199a96b668Sdanielk1977source $testdir/tester.tcl
209a96b668Sdanielk1977
21284f4acaSdanielk1977ifcapable !subquery {
22284f4acaSdanielk1977  finish_test
23284f4acaSdanielk1977  return
24284f4acaSdanielk1977}
25284f4acaSdanielk1977
269a96b668Sdanielk1977# Return the number of OpenEphemeral instructions used in the
279a96b668Sdanielk1977# implementation of the sql statement passed as a an argument.
289a96b668Sdanielk1977#
299a96b668Sdanielk1977proc nEphemeral {sql} {
309a96b668Sdanielk1977  set nEph 0
319a96b668Sdanielk1977  foreach op [execsql "EXPLAIN $sql"] {
329a96b668Sdanielk1977    if {$op eq "OpenEphemeral"} {incr nEph}
339a96b668Sdanielk1977  }
349a96b668Sdanielk1977  set nEph
359a96b668Sdanielk1977}
369a96b668Sdanielk1977
379a96b668Sdanielk1977# This proc works the same way as execsql, except that the number
389a96b668Sdanielk1977# of OpenEphemeral instructions used in the implementation of the
399a96b668Sdanielk1977# statement is inserted into the start of the returned list.
409a96b668Sdanielk1977#
419a96b668Sdanielk1977proc exec_neph {sql} {
429a96b668Sdanielk1977  return [concat [nEphemeral $sql] [execsql $sql]]
439a96b668Sdanielk1977}
449a96b668Sdanielk1977
459a96b668Sdanielk1977do_test in3-1.1 {
469a96b668Sdanielk1977  execsql {
479a96b668Sdanielk1977    CREATE TABLE t1(a PRIMARY KEY, b);
489a96b668Sdanielk1977    INSERT INTO t1 VALUES(1, 2);
499a96b668Sdanielk1977    INSERT INTO t1 VALUES(3, 4);
509a96b668Sdanielk1977    INSERT INTO t1 VALUES(5, 6);
519a96b668Sdanielk1977  }
529a96b668Sdanielk1977} {}
539a96b668Sdanielk1977
549a96b668Sdanielk1977# All of these queries should avoid using a temp-table:
559a96b668Sdanielk1977#
569a96b668Sdanielk1977do_test in3-1.2 {
579a96b668Sdanielk1977  exec_neph { SELECT rowid FROM t1 WHERE rowid IN (SELECT rowid FROM t1); }
589a96b668Sdanielk1977} {0 1 2 3}
599a96b668Sdanielk1977do_test in3-1.3 {
609a96b668Sdanielk1977  exec_neph { SELECT a FROM t1 WHERE a IN (SELECT a FROM t1); }
619a96b668Sdanielk1977} {0 1 3 5}
629a96b668Sdanielk1977do_test in3-1.4 {
639a96b668Sdanielk1977  exec_neph { SELECT rowid FROM t1 WHERE rowid+0 IN (SELECT rowid FROM t1); }
649a96b668Sdanielk1977} {0 1 2 3}
659a96b668Sdanielk1977do_test in3-1.5 {
669a96b668Sdanielk1977  exec_neph { SELECT a FROM t1 WHERE a+0 IN (SELECT a FROM t1); }
679a96b668Sdanielk1977} {0 1 3 5}
689a96b668Sdanielk1977
699a96b668Sdanielk1977# Because none of the sub-select queries in the following statements
709a96b668Sdanielk1977# match the pattern ("SELECT <column> FROM <table>"), the following do
719a96b668Sdanielk1977# require a temp table.
729a96b668Sdanielk1977#
739a96b668Sdanielk1977do_test in3-1.6 {
749a96b668Sdanielk1977  exec_neph { SELECT rowid FROM t1 WHERE rowid IN (SELECT rowid+0 FROM t1); }
759a96b668Sdanielk1977} {1 1 2 3}
769a96b668Sdanielk1977do_test in3-1.7 {
779a96b668Sdanielk1977  exec_neph { SELECT a FROM t1 WHERE a IN (SELECT a+0 FROM t1); }
789a96b668Sdanielk1977} {1 1 3 5}
799a96b668Sdanielk1977do_test in3-1.8 {
809a96b668Sdanielk1977  exec_neph { SELECT a FROM t1 WHERE a IN (SELECT a FROM t1 WHERE 1); }
819a96b668Sdanielk1977} {1 1 3 5}
829a96b668Sdanielk1977do_test in3-1.9 {
839a96b668Sdanielk1977  exec_neph { SELECT a FROM t1 WHERE a IN (SELECT a FROM t1 GROUP BY a); }
849a96b668Sdanielk1977} {1 1 3 5}
859a96b668Sdanielk1977
869a96b668Sdanielk1977# This should not use a temp-table. Even though the sub-select does
879a96b668Sdanielk1977# not exactly match the pattern "SELECT <column> FROM <table>", in
889a96b668Sdanielk1977# this case the ORDER BY is a no-op and can be ignored.
899a96b668Sdanielk1977do_test in3-1.10 {
909a96b668Sdanielk1977  exec_neph { SELECT a FROM t1 WHERE a IN (SELECT a FROM t1 ORDER BY a); }
919a96b668Sdanielk1977} {0 1 3 5}
929a96b668Sdanielk1977
939a96b668Sdanielk1977# These do use the temp-table. Adding the LIMIT clause means the
949a96b668Sdanielk1977# ORDER BY cannot be ignored.
959a96b668Sdanielk1977do_test in3-1.11 {
969a96b668Sdanielk1977  exec_neph {SELECT a FROM t1 WHERE a IN (SELECT a FROM t1 ORDER BY a LIMIT 1)}
979a96b668Sdanielk1977} {1 1}
989a96b668Sdanielk1977do_test in3-1.12 {
999a96b668Sdanielk1977  exec_neph {
1009a96b668Sdanielk1977    SELECT a FROM t1 WHERE a IN (SELECT a FROM t1 ORDER BY a LIMIT 1 OFFSET 1)
1019a96b668Sdanielk1977  }
1029a96b668Sdanielk1977} {1 3}
1039a96b668Sdanielk1977
1049a96b668Sdanielk1977# Has to use a temp-table because of the compound sub-select.
1059a96b668Sdanielk1977#
106*de3e41e3Sdanielk1977ifcapable compound {
1079a96b668Sdanielk1977  do_test in3-1.13 {
1089a96b668Sdanielk1977    exec_neph {
1099a96b668Sdanielk1977      SELECT a FROM t1 WHERE a IN (
1109a96b668Sdanielk1977        SELECT a FROM t1 UNION ALL SELECT a FROM t1
1119a96b668Sdanielk1977      )
1129a96b668Sdanielk1977    }
1139a96b668Sdanielk1977  } {1 1 3 5}
114*de3e41e3Sdanielk1977}
1159a96b668Sdanielk1977
1169a96b668Sdanielk1977# The first of these queries has to use the temp-table, because the
1179a96b668Sdanielk1977# collation sequence used for the index on "t1.a" does not match the
1189a96b668Sdanielk1977# collation sequence used by the "IN" comparison. The second does not
1199a96b668Sdanielk1977# require a temp-table, because the collation sequences match.
1209a96b668Sdanielk1977#
1219a96b668Sdanielk1977do_test in3-1.14 {
1229a96b668Sdanielk1977  exec_neph { SELECT a FROM t1 WHERE a COLLATE nocase IN (SELECT a FROM t1) }
1239a96b668Sdanielk1977} {1 1 3 5}
1249a96b668Sdanielk1977do_test in3-1.15 {
1259a96b668Sdanielk1977  exec_neph { SELECT a FROM t1 WHERE a COLLATE binary IN (SELECT a FROM t1) }
1269a96b668Sdanielk1977} {0 1 3 5}
1279a96b668Sdanielk1977
1289a96b668Sdanielk1977# Neither of these queries require a temp-table. The collation sequence
1299a96b668Sdanielk1977# makes no difference when using a rowid.
1309a96b668Sdanielk1977#
1319a96b668Sdanielk1977do_test in3-1.16 {
1329a96b668Sdanielk1977  exec_neph {SELECT a FROM t1 WHERE a COLLATE nocase IN (SELECT rowid FROM t1)}
1339a96b668Sdanielk1977} {0 1 3}
1349a96b668Sdanielk1977do_test in3-1.17 {
1359a96b668Sdanielk1977  exec_neph {SELECT a FROM t1 WHERE a COLLATE binary IN (SELECT rowid FROM t1)}
1369a96b668Sdanielk1977} {0 1 3}
1379a96b668Sdanielk1977
1389a96b668Sdanielk1977# The following tests - in3.2.* - test a bug that was difficult to track
1399a96b668Sdanielk1977# down during development. They are not particularly well focused.
1409a96b668Sdanielk1977#
1419a96b668Sdanielk1977do_test in3-2.1 {
1429a96b668Sdanielk1977  execsql {
1439a96b668Sdanielk1977    DROP TABLE IF EXISTS t1;
1449a96b668Sdanielk1977    CREATE TABLE t1(w int, x int, y int);
1459a96b668Sdanielk1977    CREATE TABLE t2(p int, q int, r int, s int);
1469a96b668Sdanielk1977  }
1479a96b668Sdanielk1977  for {set i 1} {$i<=100} {incr i} {
1489a96b668Sdanielk1977    set w $i
1499a96b668Sdanielk1977    set x [expr {int(log($i)/log(2))}]
1509a96b668Sdanielk1977    set y [expr {$i*$i + 2*$i + 1}]
1519a96b668Sdanielk1977    execsql "INSERT INTO t1 VALUES($w,$x,$y)"
1529a96b668Sdanielk1977  }
1539a96b668Sdanielk1977  set maxy [execsql {select max(y) from t1}]
1549a96b668Sdanielk1977  db eval { INSERT INTO t2 SELECT 101-w, x, $maxy+1-y, y FROM t1 }
1559a96b668Sdanielk1977} {}
1569a96b668Sdanielk1977do_test in3-2.2 {
1579a96b668Sdanielk1977  execsql {
1589a96b668Sdanielk1977    SELECT rowid
1599a96b668Sdanielk1977    FROM t1
1609a96b668Sdanielk1977    WHERE rowid IN (SELECT rowid FROM t1 WHERE rowid IN (1, 2));
1619a96b668Sdanielk1977  }
1629a96b668Sdanielk1977} {1 2}
1639a96b668Sdanielk1977do_test in3-2.3 {
1649a96b668Sdanielk1977  execsql {
1659a96b668Sdanielk1977    select rowid from t1 where rowid IN (-1,2,4)
1669a96b668Sdanielk1977  }
1679a96b668Sdanielk1977} {2 4}
1689a96b668Sdanielk1977do_test in3-2.4 {
1699a96b668Sdanielk1977  execsql {
1709a96b668Sdanielk1977    SELECT rowid FROM t1 WHERE rowid IN
1719a96b668Sdanielk1977       (select rowid from t1 where rowid IN (-1,2,4))
1729a96b668Sdanielk1977  }
1739a96b668Sdanielk1977} {2 4}
1749a96b668Sdanielk1977
1759a96b668Sdanielk1977#-------------------------------------------------------------------------
1769a96b668Sdanielk1977# This next block of tests - in3-3.* - verify that column affinity is
1779a96b668Sdanielk1977# correctly handled in cases where an index might be used to optimise
1789a96b668Sdanielk1977# an IN (SELECT) expression.
1799a96b668Sdanielk1977#
1809a96b668Sdanielk1977do_test in3-3.1 {
1819a96b668Sdanielk1977  catch {execsql {
1829a96b668Sdanielk1977    DROP TABLE t1;
1839a96b668Sdanielk1977    DROP TABLE t2;
1849a96b668Sdanielk1977  }}
1859a96b668Sdanielk1977
1869a96b668Sdanielk1977  execsql {
1879a96b668Sdanielk1977
1889a96b668Sdanielk1977    CREATE TABLE t1(a BLOB, b NUMBER ,c TEXT);
1899a96b668Sdanielk1977    CREATE UNIQUE INDEX t1_i1 ON t1(a);        /* no affinity */
1909a96b668Sdanielk1977    CREATE UNIQUE INDEX t1_i2 ON t1(b);        /* numeric affinity */
1919a96b668Sdanielk1977    CREATE UNIQUE INDEX t1_i3 ON t1(c);        /* text affinity */
1929a96b668Sdanielk1977
1939a96b668Sdanielk1977    CREATE TABLE t2(x BLOB, y NUMBER, z TEXT);
1949a96b668Sdanielk1977    CREATE UNIQUE INDEX t2_i1 ON t2(x);        /* no affinity */
1959a96b668Sdanielk1977    CREATE UNIQUE INDEX t2_i2 ON t2(y);        /* numeric affinity */
1969a96b668Sdanielk1977    CREATE UNIQUE INDEX t2_i3 ON t2(z);        /* text affinity */
1979a96b668Sdanielk1977
1989a96b668Sdanielk1977    INSERT INTO t1 VALUES(1, 1, 1);
1999a96b668Sdanielk1977    INSERT INTO t2 VALUES('1', '1', '1');
2009a96b668Sdanielk1977  }
2019a96b668Sdanielk1977} {}
2029a96b668Sdanielk1977
2039a96b668Sdanielk1977do_test in3-3.2 {
2049a96b668Sdanielk1977  # No affinity is applied before comparing "x" and "a". Therefore
2059a96b668Sdanielk1977  # the index can be used (the comparison is false, text!=number).
2069a96b668Sdanielk1977  exec_neph { SELECT x IN (SELECT a FROM t1) FROM t2 }
2079a96b668Sdanielk1977} {0 0}
2089a96b668Sdanielk1977do_test in3-3.3 {
2099a96b668Sdanielk1977  # Logically, numeric affinity is applied to both sides before
2109a96b668Sdanielk1977  # the comparison.  Therefore it is possible to use index t1_i2.
2119a96b668Sdanielk1977  exec_neph { SELECT x IN (SELECT b FROM t1) FROM t2 }
2129a96b668Sdanielk1977} {0 1}
2139a96b668Sdanielk1977do_test in3-3.4 {
2149a96b668Sdanielk1977  # No affinity is applied before the comparison takes place. Making
2159a96b668Sdanielk1977  # it possible to use index t1_i3.
2169a96b668Sdanielk1977  exec_neph { SELECT x IN (SELECT c FROM t1) FROM t2 }
2179a96b668Sdanielk1977} {0 1}
2189a96b668Sdanielk1977
2199a96b668Sdanielk1977do_test in3-3.5 {
2209a96b668Sdanielk1977  # Numeric affinity should be applied to each side before the comparison
2219a96b668Sdanielk1977  # takes place. Therefore we cannot use index t1_i1, which has no affinity.
2229a96b668Sdanielk1977  exec_neph { SELECT y IN (SELECT a FROM t1) FROM t2 }
2239a96b668Sdanielk1977} {1 1}
2249a96b668Sdanielk1977do_test in3-3.6 {
2259a96b668Sdanielk1977  # Numeric affinity is applied to both sides before
2269a96b668Sdanielk1977  # the comparison.  Therefore it is possible to use index t1_i2.
2279a96b668Sdanielk1977  exec_neph { SELECT y IN (SELECT b FROM t1) FROM t2 }
2289a96b668Sdanielk1977} {0 1}
2299a96b668Sdanielk1977do_test in3-3.7 {
2309a96b668Sdanielk1977  # Numeric affinity is applied before the comparison takes place.
2319a96b668Sdanielk1977  # Making it impossible to use index t1_i3.
2329a96b668Sdanielk1977  exec_neph { SELECT y IN (SELECT c FROM t1) FROM t2 }
2339a96b668Sdanielk1977} {1 1}
2349a96b668Sdanielk1977
2359a96b668Sdanielk1977#---------------------------------------------------------------------
2369a96b668Sdanielk1977#
2379a96b668Sdanielk1977# Test using a multi-column index.
2389a96b668Sdanielk1977#
2399a96b668Sdanielk1977do_test in3-4.1 {
2409a96b668Sdanielk1977  execsql {
2419a96b668Sdanielk1977    CREATE TABLE t3(a, b, c);
2429a96b668Sdanielk1977    CREATE UNIQUE INDEX t3_i ON t3(b, a);
2439a96b668Sdanielk1977  }
2449a96b668Sdanielk1977
2459a96b668Sdanielk1977  execsql {
2469a96b668Sdanielk1977    INSERT INTO t3 VALUES(1, 'numeric', 2);
2479a96b668Sdanielk1977    INSERT INTO t3 VALUES(2, 'text', 2);
2489a96b668Sdanielk1977    INSERT INTO t3 VALUES(3, 'real', 2);
2499a96b668Sdanielk1977    INSERT INTO t3 VALUES(4, 'none', 2);
2509a96b668Sdanielk1977  }
2519a96b668Sdanielk1977} {}
2529a96b668Sdanielk1977do_test in3-4.2 {
2539a96b668Sdanielk1977  exec_neph { SELECT 'text' IN (SELECT b FROM t3) }
2549a96b668Sdanielk1977} {0 1}
2559a96b668Sdanielk1977do_test in3-4.3 {
2569a96b668Sdanielk1977  exec_neph { SELECT 'TEXT' COLLATE nocase IN (SELECT b FROM t3) }
2579a96b668Sdanielk1977} {1 1}
2589a96b668Sdanielk1977do_test in3-4.4 {
2599a96b668Sdanielk1977  # A temp table must be used because t3_i.b is not guaranteed to be unique.
2609a96b668Sdanielk1977  exec_neph { SELECT b FROM t3 WHERE b IN (SELECT b FROM t3) }
2619a96b668Sdanielk1977} {1 none numeric real text}
2629a96b668Sdanielk1977do_test in3-4.5 {
2639a96b668Sdanielk1977  execsql { CREATE UNIQUE INDEX t3_i2 ON t3(b) }
2649a96b668Sdanielk1977  exec_neph { SELECT b FROM t3 WHERE b IN (SELECT b FROM t3) }
2659a96b668Sdanielk1977} {0 none numeric real text}
2669a96b668Sdanielk1977do_test in3-4.6 {
2679a96b668Sdanielk1977  execsql { DROP INDEX t3_i2 }
2689a96b668Sdanielk1977} {}
2699a96b668Sdanielk1977
270b2b95d41Sdanielk1977# The following two test cases verify that ticket #2991 has been fixed.
271b2b95d41Sdanielk1977#
272b2b95d41Sdanielk1977do_test in3-5.1 {
273b2b95d41Sdanielk1977  execsql {
274b2b95d41Sdanielk1977    CREATE TABLE Folders(
275b2b95d41Sdanielk1977      folderid INTEGER PRIMARY KEY,
276b2b95d41Sdanielk1977      parentid INTEGER,
277b2b95d41Sdanielk1977      rootid INTEGER,
278b2b95d41Sdanielk1977      path VARCHAR(255)
279b2b95d41Sdanielk1977    );
280b2b95d41Sdanielk1977  }
281b2b95d41Sdanielk1977} {}
282b2b95d41Sdanielk1977do_test in3-5.2 {
283b2b95d41Sdanielk1977  catchsql {
284b2b95d41Sdanielk1977    DELETE FROM Folders WHERE folderid IN
285b2b95d41Sdanielk1977    (SELECT folderid FROM Folder WHERE path LIKE 'C:\MP3\Albums\' || '%');
286b2b95d41Sdanielk1977  }
287b2b95d41Sdanielk1977} {1 {no such table: Folder}}
288b2b95d41Sdanielk1977
2899a96b668Sdanielk1977finish_test
290