xref: /sqlite-3.40.0/test/where2.test (revision 8210233c)
1a611040eSdrh# 2005 July 28
2a611040eSdrh#
3a611040eSdrh# The author disclaims copyright to this source code.  In place of
4a611040eSdrh# a legal notice, here is a blessing:
5a611040eSdrh#
6a611040eSdrh#    May you do good and not evil.
7a611040eSdrh#    May you find forgiveness for yourself and forgive others.
8a611040eSdrh#    May you share freely, never taking more than you give.
9a611040eSdrh#
10a611040eSdrh#***********************************************************************
11a611040eSdrh# This file implements regression tests for SQLite library.  The
12a611040eSdrh# focus of this file is testing the use of indices in WHERE clauses
13a611040eSdrh# based on recent changes to the optimizer.
14a611040eSdrh#
159373b018Sdrh# $Id: where2.test,v 1.15 2009/02/02 01:50:40 drh Exp $
16a611040eSdrh
17a611040eSdrhset testdir [file dirname $argv0]
18a611040eSdrhsource $testdir/tester.tcl
19a611040eSdrh
20a611040eSdrh# Build some test data
21a611040eSdrh#
22a611040eSdrhdo_test where2-1.0 {
23a611040eSdrh  execsql {
24a611040eSdrh    BEGIN;
25a611040eSdrh    CREATE TABLE t1(w int, x int, y int, z int);
26a611040eSdrh  }
27a611040eSdrh  for {set i 1} {$i<=100} {incr i} {
28a611040eSdrh    set w $i
29a611040eSdrh    set x [expr {int(log($i)/log(2))}]
30a611040eSdrh    set y [expr {$i*$i + 2*$i + 1}]
31a611040eSdrh    set z [expr {$x+$y}]
323bdca9c9Sdanielk1977    ifcapable tclvar {
33a611040eSdrh      execsql {INSERT INTO t1 VALUES($::w,$::x,$::y,$::z)}
343bdca9c9Sdanielk1977    } else {
353bdca9c9Sdanielk1977      execsql {INSERT INTO t1 VALUES(:w,:x,:y,:z)}
363bdca9c9Sdanielk1977    }
37a611040eSdrh  }
38a611040eSdrh  execsql {
39a611040eSdrh    CREATE UNIQUE INDEX i1w ON t1(w);
40a611040eSdrh    CREATE INDEX i1xy ON t1(x,y);
41a611040eSdrh    CREATE INDEX i1zyx ON t1(z,y,x);
42a611040eSdrh    COMMIT;
43a611040eSdrh  }
44a611040eSdrh} {}
45a611040eSdrh
46a611040eSdrh# Do an SQL statement.  Append the search count to the end of the result.
47a611040eSdrh#
48a611040eSdrhproc count sql {
49a611040eSdrh  set ::sqlite_search_count 0
50a611040eSdrh  return [concat [execsql $sql] $::sqlite_search_count]
51a611040eSdrh}
52a611040eSdrh
53a611040eSdrh# This procedure executes the SQL.  Then it checks to see if the OP_Sort
54a611040eSdrh# opcode was executed.  If an OP_Sort did occur, then "sort" is appended
55a611040eSdrh# to the result.  If no OP_Sort happened, then "nosort" is appended.
56a611040eSdrh#
57a611040eSdrh# This procedure is used to check to make sure sorting is or is not
58a611040eSdrh# occurring as expected.
59a611040eSdrh#
60a611040eSdrhproc cksort {sql} {
61a611040eSdrh  set data [execsql $sql]
62d1d38488Sdrh  if {[db status sort]} {set x sort} {set x nosort}
63a611040eSdrh  lappend data $x
64a611040eSdrh  return $data
65a611040eSdrh}
66a611040eSdrh
67a611040eSdrh# This procedure executes the SQL.  Then it appends to the result the
68a611040eSdrh# "sort" or "nosort" keyword (as in the cksort procedure above) then
697c171098Sdrh# it appends the name of the table and index used.
70a611040eSdrh#
71a611040eSdrhproc queryplan {sql} {
72a611040eSdrh  set ::sqlite_sort_count 0
73a611040eSdrh  set data [execsql $sql]
74a611040eSdrh  if {$::sqlite_sort_count} {set x sort} {set x nosort}
75a611040eSdrh  lappend data $x
76ae70cf18Sdrh  set eqp [execsql "EXPLAIN QUERY PLAN $sql"]
77ae70cf18Sdrh  # puts eqp=$eqp
78ae70cf18Sdrh  foreach {a b c x} $eqp {
79*8210233cSdrh    if {[regexp {SCAN CONSTANT} $x]} {
80*8210233cSdrh      # noop
81*8210233cSdrh    } elseif {[regexp {(SCAN|SEARCH) (\w+ AS )?(\w+) USING.* INDEX (\w+)\y} \
82*8210233cSdrh        $x all ss as tab idx]} {
83ae70cf18Sdrh      lappend data $tab $idx
84*8210233cSdrh    } elseif {[regexp {(SCAN|SEARCH) (\w+ AS )?(\w+)\y} $x all ss as tab]} {
85ae70cf18Sdrh      lappend data $tab *
86ae70cf18Sdrh    }
87ae70cf18Sdrh  }
88ae70cf18Sdrh  return $data
89a611040eSdrh}
90a611040eSdrh
91a611040eSdrh
92a611040eSdrh# Prefer a UNIQUE index over another index.
93a611040eSdrh#
94a611040eSdrhdo_test where2-1.1 {
95a611040eSdrh  queryplan {
96a611040eSdrh    SELECT * FROM t1 WHERE w=85 AND x=6 AND y=7396
97a611040eSdrh  }
98a611040eSdrh} {85 6 7396 7402 nosort t1 i1w}
99a611040eSdrh
100a611040eSdrh# Always prefer a rowid== constraint over any other index.
101a611040eSdrh#
102a611040eSdrhdo_test where2-1.3 {
103a611040eSdrh  queryplan {
104a611040eSdrh    SELECT * FROM t1 WHERE w=85 AND x=6 AND y=7396 AND rowid=85
105a611040eSdrh  }
106a611040eSdrh} {85 6 7396 7402 nosort t1 *}
107a611040eSdrh
108a611040eSdrh# When constrained by a UNIQUE index, the ORDER BY clause is always ignored.
109a611040eSdrh#
110a611040eSdrhdo_test where2-2.1 {
111a611040eSdrh  queryplan {
1129373b018Sdrh    SELECT * FROM t1 WHERE w=85 ORDER BY random();
113a611040eSdrh  }
114a611040eSdrh} {85 6 7396 7402 nosort t1 i1w}
115a611040eSdrhdo_test where2-2.2 {
116a611040eSdrh  queryplan {
1179373b018Sdrh    SELECT * FROM t1 WHERE x=6 AND y=7396 ORDER BY random();
118a611040eSdrh  }
119a611040eSdrh} {85 6 7396 7402 sort t1 i1xy}
120a611040eSdrhdo_test where2-2.3 {
121a611040eSdrh  queryplan {
1229373b018Sdrh    SELECT * FROM t1 WHERE rowid=85 AND x=6 AND y=7396 ORDER BY random();
123a611040eSdrh  }
124a611040eSdrh} {85 6 7396 7402 nosort t1 *}
125a611040eSdrh
126434a9314Sdrh# Ticket [65bdeb9739605cc22966f49208452996ff29a640] 2014-02-26
127434a9314Sdrh# Make sure "ORDER BY random" does not gets optimized out.
128434a9314Sdrh#
129434a9314Sdrhdo_test where2-2.4 {
130434a9314Sdrh  db eval {
131434a9314Sdrh    CREATE TABLE x1(a INTEGER PRIMARY KEY, b DEFAULT 1);
132434a9314Sdrh    WITH RECURSIVE
133434a9314Sdrh       cnt(x) AS (VALUES(1) UNION ALL SELECT x+1 FROM cnt WHERE x<50)
134434a9314Sdrh    INSERT INTO x1 SELECT x, 1 FROM cnt;
135434a9314Sdrh    CREATE TABLE x2(x INTEGER PRIMARY KEY);
136434a9314Sdrh    INSERT INTO x2 VALUES(1);
137434a9314Sdrh  }
138434a9314Sdrh  set sql {SELECT * FROM x1, x2 WHERE x=1 ORDER BY random()}
139434a9314Sdrh  set out1 [db eval $sql]
140434a9314Sdrh  set out2 [db eval $sql]
141434a9314Sdrh  set out3 [db eval $sql]
142434a9314Sdrh  expr {$out1!=$out2 && $out2!=$out3}
143434a9314Sdrh} {1}
144434a9314Sdrhdo_execsql_test where2-2.5 {
145434a9314Sdrh  -- random() is not optimized out
146434a9314Sdrh  EXPLAIN SELECT * FROM x1, x2 WHERE x=1 ORDER BY random();
147434a9314Sdrh} {/ random/}
148434a9314Sdrhdo_execsql_test where2-2.5b {
149434a9314Sdrh  -- random() is not optimized out
150434a9314Sdrh  EXPLAIN SELECT * FROM x1, x2 WHERE x=1 ORDER BY random();
151434a9314Sdrh} {/ SorterOpen /}
152434a9314Sdrhdo_execsql_test where2-2.6 {
153434a9314Sdrh  -- other constant functions are optimized out
154434a9314Sdrh  EXPLAIN SELECT * FROM x1, x2 WHERE x=1 ORDER BY abs(5);
155434a9314Sdrh} {~/ abs/}
156434a9314Sdrhdo_execsql_test where2-2.6b {
157434a9314Sdrh  -- other constant functions are optimized out
158434a9314Sdrh  EXPLAIN SELECT * FROM x1, x2 WHERE x=1 ORDER BY abs(5);
159434a9314Sdrh} {~/ SorterOpen /}
160434a9314Sdrh
161434a9314Sdrh
162a611040eSdrh
163a611040eSdrh# Efficient handling of forward and reverse table scans.
164a611040eSdrh#
165a611040eSdrhdo_test where2-3.1 {
166a611040eSdrh  queryplan {
167a611040eSdrh    SELECT * FROM t1 ORDER BY rowid LIMIT 2
168a611040eSdrh  }
169a611040eSdrh} {1 0 4 4 2 1 9 10 nosort t1 *}
170a611040eSdrhdo_test where2-3.2 {
171a611040eSdrh  queryplan {
172a611040eSdrh    SELECT * FROM t1 ORDER BY rowid DESC LIMIT 2
173a611040eSdrh  }
174a611040eSdrh} {100 6 10201 10207 99 6 10000 10006 nosort t1 *}
175a611040eSdrh
176a611040eSdrh# The IN operator can be used by indices at multiple layers
177a611040eSdrh#
1781576cd92Sdanielk1977ifcapable subquery {
179a611040eSdrh  do_test where2-4.1 {
180a611040eSdrh    queryplan {
181a611040eSdrh      SELECT * FROM t1 WHERE z IN (10207,10006) AND y IN (10000,10201)
182a611040eSdrh                       AND x>0 AND x<10
183a611040eSdrh      ORDER BY w
184a611040eSdrh    }
185a611040eSdrh  } {99 6 10000 10006 100 6 10201 10207 sort t1 i1zyx}
186a611040eSdrh  do_test where2-4.2 {
187a611040eSdrh    queryplan {
188a611040eSdrh      SELECT * FROM t1 WHERE z IN (10207,10006) AND y=10000
189a611040eSdrh                       AND x>0 AND x<10
190a611040eSdrh      ORDER BY w
191a611040eSdrh    }
192a611040eSdrh  } {99 6 10000 10006 sort t1 i1zyx}
193a611040eSdrh  do_test where2-4.3 {
194a611040eSdrh    queryplan {
195a611040eSdrh      SELECT * FROM t1 WHERE z=10006 AND y IN (10000,10201)
196a611040eSdrh                       AND x>0 AND x<10
197a611040eSdrh      ORDER BY w
198a611040eSdrh    }
199a611040eSdrh  } {99 6 10000 10006 sort t1 i1zyx}
200ff890793Sdanielk1977  ifcapable compound {
201a611040eSdrh    do_test where2-4.4 {
202a611040eSdrh      queryplan {
203a611040eSdrh        SELECT * FROM t1 WHERE z IN (SELECT 10207 UNION SELECT 10006)
204a611040eSdrh                         AND y IN (10000,10201)
205a611040eSdrh                         AND x>0 AND x<10
206a611040eSdrh        ORDER BY w
207a611040eSdrh      }
208a611040eSdrh    } {99 6 10000 10006 100 6 10201 10207 sort t1 i1zyx}
209a611040eSdrh    do_test where2-4.5 {
210a611040eSdrh      queryplan {
211a611040eSdrh        SELECT * FROM t1 WHERE z IN (SELECT 10207 UNION SELECT 10006)
212a611040eSdrh                         AND y IN (SELECT 10000 UNION SELECT 10201)
213a611040eSdrh                         AND x>0 AND x<10
214a611040eSdrh        ORDER BY w
215a611040eSdrh      }
216a611040eSdrh    } {99 6 10000 10006 100 6 10201 10207 sort t1 i1zyx}
217ff890793Sdanielk1977  }
2181b8fc65bSdrh  do_test where2-4.6a {
219a611040eSdrh    queryplan {
220a611040eSdrh      SELECT * FROM t1
221a611040eSdrh       WHERE x IN (1,2,3,4,5,6,7,8)
222a611040eSdrh         AND y IN (10000,10001,10002,10003,10004,10005)
2231b8fc65bSdrh       ORDER BY x
2241b8fc65bSdrh    }
2251b8fc65bSdrh  } {99 6 10000 10006 nosort t1 i1xy}
2261b8fc65bSdrh  do_test where2-4.6b {
2271b8fc65bSdrh    queryplan {
2281b8fc65bSdrh      SELECT * FROM t1
2291b8fc65bSdrh       WHERE x IN (1,2,3,4,5,6,7,8)
2301b8fc65bSdrh         AND y IN (10000,10001,10002,10003,10004,10005)
2311b8fc65bSdrh       ORDER BY x DESC
2321b8fc65bSdrh    }
2332d96b934Sdrh  } {99 6 10000 10006 nosort t1 i1xy}
2341b8fc65bSdrh  do_test where2-4.6c {
2351b8fc65bSdrh    queryplan {
2361b8fc65bSdrh      SELECT * FROM t1
2371b8fc65bSdrh       WHERE x IN (1,2,3,4,5,6,7,8)
2381b8fc65bSdrh         AND y IN (10000,10001,10002,10003,10004,10005)
2391b8fc65bSdrh       ORDER BY x, y
2401b8fc65bSdrh    }
2411b8fc65bSdrh  } {99 6 10000 10006 nosort t1 i1xy}
2421b8fc65bSdrh  do_test where2-4.6d {
2431b8fc65bSdrh    queryplan {
2441b8fc65bSdrh      SELECT * FROM t1
2451b8fc65bSdrh       WHERE x IN (1,2,3,4,5,6,7,8)
2461b8fc65bSdrh         AND y IN (10000,10001,10002,10003,10004,10005)
2471b8fc65bSdrh       ORDER BY x, y DESC
248a611040eSdrh    }
249a611040eSdrh  } {99 6 10000 10006 sort t1 i1xy}
250a611040eSdrh
251a611040eSdrh  # Duplicate entires on the RHS of an IN operator do not cause duplicate
252a611040eSdrh  # output rows.
253a611040eSdrh  #
2541b8fc65bSdrh  do_test where2-4.6x {
255a611040eSdrh    queryplan {
256a611040eSdrh      SELECT * FROM t1 WHERE z IN (10207,10006,10006,10207)
257a611040eSdrh      ORDER BY w
258a611040eSdrh    }
259a611040eSdrh  } {99 6 10000 10006 100 6 10201 10207 sort t1 i1zyx}
2601b8fc65bSdrh  do_test where2-4.6y {
2611b8fc65bSdrh    queryplan {
2621b8fc65bSdrh      SELECT * FROM t1 WHERE z IN (10207,10006,10006,10207)
2631b8fc65bSdrh      ORDER BY w DESC
2641b8fc65bSdrh    }
2651b8fc65bSdrh  } {100 6 10201 10207 99 6 10000 10006 sort t1 i1zyx}
266ff890793Sdanielk1977  ifcapable compound {
267a611040eSdrh    do_test where2-4.7 {
268a611040eSdrh      queryplan {
269a611040eSdrh        SELECT * FROM t1 WHERE z IN (
270a611040eSdrh           SELECT 10207 UNION ALL SELECT 10006
271a611040eSdrh           UNION ALL SELECT 10006 UNION ALL SELECT 10207)
272a611040eSdrh        ORDER BY w
273a611040eSdrh      }
274a611040eSdrh    } {99 6 10000 10006 100 6 10201 10207 sort t1 i1zyx}
275ff890793Sdanielk1977  }
276a611040eSdrh
2771576cd92Sdanielk1977} ;# ifcapable subquery
2781576cd92Sdanielk1977
279a611040eSdrh# The use of an IN operator disables the index as a sorter.
280a611040eSdrh#
281a611040eSdrhdo_test where2-5.1 {
282a611040eSdrh  queryplan {
283a611040eSdrh    SELECT * FROM t1 WHERE w=99 ORDER BY w
284a611040eSdrh  }
285a611040eSdrh} {99 6 10000 10006 nosort t1 i1w}
2861576cd92Sdanielk1977
2871576cd92Sdanielk1977ifcapable subquery {
2881b8fc65bSdrh  do_test where2-5.2a {
289a611040eSdrh    queryplan {
290a611040eSdrh      SELECT * FROM t1 WHERE w IN (99) ORDER BY w
291a611040eSdrh    }
2921b8fc65bSdrh  } {99 6 10000 10006 nosort t1 i1w}
2931b8fc65bSdrh  do_test where2-5.2b {
2941b8fc65bSdrh    queryplan {
2951b8fc65bSdrh      SELECT * FROM t1 WHERE w IN (99) ORDER BY w DESC
2961b8fc65bSdrh    }
2972d96b934Sdrh  } {99 6 10000 10006 nosort t1 i1w}
2981576cd92Sdanielk1977}
299a611040eSdrh
3006c30be8eSdrh# Verify that OR clauses get translated into IN operators.
3016c30be8eSdrh#
3021576cd92Sdanielk1977set ::idx {}
3031576cd92Sdanielk1977ifcapable subquery {set ::idx i1w}
3043e355807Sdrhdo_test where2-6.1.1 {
3056c30be8eSdrh  queryplan {
3066c30be8eSdrh    SELECT * FROM t1 WHERE w=99 OR w=100 ORDER BY +w
3076c30be8eSdrh  }
3081576cd92Sdanielk1977} [list 99 6 10000 10006 100 6 10201 10207 sort t1 $::idx]
3093e355807Sdrhdo_test where2-6.1.2 {
3103e355807Sdrh  queryplan {
3113e355807Sdrh    SELECT * FROM t1 WHERE 99=w OR 100=w ORDER BY +w
3123e355807Sdrh  }
3133e355807Sdrh} [list 99 6 10000 10006 100 6 10201 10207 sort t1 $::idx]
3146c30be8eSdrhdo_test where2-6.2 {
3156c30be8eSdrh  queryplan {
3166c30be8eSdrh    SELECT * FROM t1 WHERE w=99 OR w=100 OR 6=w ORDER BY +w
3176c30be8eSdrh  }
3181576cd92Sdanielk1977} [list 6 2 49 51 99 6 10000 10006 100 6 10201 10207 sort t1 $::idx]
3191576cd92Sdanielk1977
3206c30be8eSdrhdo_test where2-6.3 {
3216c30be8eSdrh  queryplan {
3226c30be8eSdrh    SELECT * FROM t1 WHERE w=99 OR w=100 OR 6=+w ORDER BY +w
3236c30be8eSdrh  }
3244fe425adSdrh} {6 2 49 51 99 6 10000 10006 100 6 10201 10207 sort t1 *}
3256c30be8eSdrhdo_test where2-6.4 {
3266c30be8eSdrh  queryplan {
3272dc29293Sdrh    SELECT *, '|' FROM t1 WHERE w=99 OR +w=100 OR 6=w ORDER BY +w
3286c30be8eSdrh  }
3292dc29293Sdrh} {6 2 49 51 | 99 6 10000 10006 | 100 6 10201 10207 | sort t1 *}
3302dc29293Sdrhdo_test where2-6.5 {
3312dc29293Sdrh  queryplan {
3322dc29293Sdrh    SELECT *, '|' FROM t1 WHERE w=99 OR y=10201 OR 6=w ORDER BY +w
3332dc29293Sdrh  }
3342dc29293Sdrh} {6 2 49 51 | 99 6 10000 10006 | 100 6 10201 10207 | sort t1 *}
3351576cd92Sdanielk1977
3361576cd92Sdanielk1977set ::idx {}
3371576cd92Sdanielk1977ifcapable subquery {set ::idx i1zyx}
3386c30be8eSdrhdo_test where2-6.5 {
3396c30be8eSdrh  queryplan {
3406c30be8eSdrh    SELECT b.* FROM t1 a, t1 b
3416c30be8eSdrh     WHERE a.w=1 AND (a.y=b.z OR b.z=10)
3426c30be8eSdrh     ORDER BY +b.w
3436c30be8eSdrh  }
3441576cd92Sdanielk1977} [list 1 0 4 4 2 1 9 10 sort a i1w b $::idx]
3456c30be8eSdrhdo_test where2-6.6 {
3466c30be8eSdrh  queryplan {
3476c30be8eSdrh    SELECT b.* FROM t1 a, t1 b
3486c30be8eSdrh     WHERE a.w=1 AND (b.z=10 OR a.y=b.z OR b.z=10)
3496c30be8eSdrh     ORDER BY +b.w
3506c30be8eSdrh  }
3511576cd92Sdanielk1977} [list 1 0 4 4 2 1 9 10 sort a i1w b $::idx]
3526c30be8eSdrh
353c1f19f95Sdanif {[permutation] != "no_optimization"} {
354c1f19f95Sdan
3553e355807Sdrh# Ticket #2249.  Make sure the OR optimization is not attempted if
3563e355807Sdrh# comparisons between columns of different affinities are needed.
3573e355807Sdrh#
3583e355807Sdrhdo_test where2-6.7 {
3593e355807Sdrh  execsql {
360165674d8Sdrh    CREATE TABLE t2249a(a TEXT UNIQUE, x CHAR(100));
3613e355807Sdrh    CREATE TABLE t2249b(b INTEGER);
362165674d8Sdrh    INSERT INTO t2249a(a) VALUES('0123');
3633e355807Sdrh    INSERT INTO t2249b VALUES(123);
3643e355807Sdrh  }
3653e355807Sdrh  queryplan {
3663e355807Sdrh    -- Because a is type TEXT and b is type INTEGER, both a and b
3673e355807Sdrh    -- will attempt to convert to NUMERIC before the comparison.
3683e355807Sdrh    -- They will thus compare equal.
3693e355807Sdrh    --
370165674d8Sdrh    SELECT b,a FROM t2249b CROSS JOIN t2249a WHERE a=b;
3713e355807Sdrh  }
3724fe425adSdrh} {123 0123 nosort t2249b * t2249a sqlite_autoindex_t2249a_1}
3733e355807Sdrhdo_test where2-6.9 {
3743e355807Sdrh  queryplan {
3753e355807Sdrh    -- The + operator removes affinity from the rhs.  No conversions
3763e355807Sdrh    -- occur and the comparison is false.  The result is an empty set.
3773e355807Sdrh    --
378165674d8Sdrh    SELECT b,a FROM t2249b CROSS JOIN t2249a WHERE a=+b;
3793e355807Sdrh  }
3804fe425adSdrh} {nosort t2249b * t2249a sqlite_autoindex_t2249a_1}
3813e355807Sdrhdo_test where2-6.9.2 {
3823e355807Sdrh  # The same thing but with the expression flipped around.
3833e355807Sdrh  queryplan {
384165674d8Sdrh    SELECT b,a FROM t2249b CROSS JOIN t2249a WHERE +b=a
3853e355807Sdrh  }
3864fe425adSdrh} {nosort t2249b * t2249a sqlite_autoindex_t2249a_1}
3873e355807Sdrhdo_test where2-6.10 {
3883e355807Sdrh  queryplan {
3893e355807Sdrh    -- Use + on both sides of the comparison to disable indices
3903e355807Sdrh    -- completely.  Make sure we get the same result.
3913e355807Sdrh    --
392165674d8Sdrh    SELECT b,a FROM t2249b CROSS JOIN t2249a WHERE +a=+b;
3933e355807Sdrh  }
3944fe425adSdrh} {nosort t2249b * t2249a sqlite_autoindex_t2249a_1}
3953e355807Sdrhdo_test where2-6.11 {
3963e355807Sdrh  # This will not attempt the OR optimization because of the a=b
3973e355807Sdrh  # comparison.
3983e355807Sdrh  queryplan {
399165674d8Sdrh    SELECT b,a FROM t2249b CROSS JOIN t2249a WHERE a=b OR a='hello';
4003e355807Sdrh  }
4014fe425adSdrh} {123 0123 nosort t2249b * t2249a sqlite_autoindex_t2249a_1}
4023e355807Sdrhdo_test where2-6.11.2 {
4033e355807Sdrh  # Permutations of the expression terms.
4043e355807Sdrh  queryplan {
405165674d8Sdrh    SELECT b,a FROM t2249b CROSS JOIN t2249a WHERE b=a OR a='hello';
4063e355807Sdrh  }
4074fe425adSdrh} {123 0123 nosort t2249b * t2249a sqlite_autoindex_t2249a_1}
4083e355807Sdrhdo_test where2-6.11.3 {
4093e355807Sdrh  # Permutations of the expression terms.
4103e355807Sdrh  queryplan {
411165674d8Sdrh    SELECT b,a FROM t2249b CROSS JOIN t2249a WHERE 'hello'=a OR b=a;
4123e355807Sdrh  }
4134fe425adSdrh} {123 0123 nosort t2249b * t2249a sqlite_autoindex_t2249a_1}
4143e355807Sdrhdo_test where2-6.11.4 {
4153e355807Sdrh  # Permutations of the expression terms.
4163e355807Sdrh  queryplan {
417165674d8Sdrh    SELECT b,a FROM t2249b CROSS JOIN t2249a WHERE a='hello' OR b=a;
4183e355807Sdrh  }
4194fe425adSdrh} {123 0123 nosort t2249b * t2249a sqlite_autoindex_t2249a_1}
420284f4acaSdanielk1977ifcapable explain&&subquery {
421284f4acaSdanielk1977  # These tests are not run if subquery support is not included in the
422284f4acaSdanielk1977  # build. This is because these tests test the "a = 1 OR a = 2" to
423284f4acaSdanielk1977  # "a IN (1, 2)" optimisation transformation, which is not enabled if
424284f4acaSdanielk1977  # subqueries and the IN operator is not available.
425284f4acaSdanielk1977  #
4263e355807Sdrh  do_test where2-6.12 {
4273e355807Sdrh    # In this case, the +b disables the affinity conflict and allows
4283e355807Sdrh    # the OR optimization to be used again.  The result is now an empty
4293e355807Sdrh    # set, the same as in where2-6.9.
4303e355807Sdrh    queryplan {
431165674d8Sdrh      SELECT b,a FROM t2249b CROSS JOIN t2249a WHERE a=+b OR a='hello';
4323e355807Sdrh    }
4334fe425adSdrh  } {nosort t2249b * t2249a sqlite_autoindex_t2249a_1}
4343e355807Sdrh  do_test where2-6.12.2 {
4353e355807Sdrh    # In this case, the +b disables the affinity conflict and allows
4363e355807Sdrh    # the OR optimization to be used again.  The result is now an empty
4373e355807Sdrh    # set, the same as in where2-6.9.
4383e355807Sdrh    queryplan {
439165674d8Sdrh      SELECT b,a FROM t2249b CROSS JOIN t2249a WHERE a='hello' OR +b=a;
4403e355807Sdrh    }
4414fe425adSdrh  } {nosort t2249b * t2249a sqlite_autoindex_t2249a_1}
4423e355807Sdrh  do_test where2-6.12.3 {
4433e355807Sdrh    # In this case, the +b disables the affinity conflict and allows
4443e355807Sdrh    # the OR optimization to be used again.  The result is now an empty
4453e355807Sdrh    # set, the same as in where2-6.9.
4463e355807Sdrh    queryplan {
447165674d8Sdrh      SELECT b,a FROM t2249b CROSS JOIN t2249a WHERE +b=a OR a='hello';
4483e355807Sdrh    }
4494fe425adSdrh  } {nosort t2249b * t2249a sqlite_autoindex_t2249a_1}
4503e355807Sdrh  do_test where2-6.13 {
4513e355807Sdrh    # The addition of +a on the second term disabled the OR optimization.
4523e355807Sdrh    # But we should still get the same empty-set result as in where2-6.9.
4533e355807Sdrh    queryplan {
454165674d8Sdrh      SELECT b,a FROM t2249b CROSS JOIN t2249a WHERE a=+b OR +a='hello';
4553e355807Sdrh    }
4564fe425adSdrh  } {nosort t2249b * t2249a sqlite_autoindex_t2249a_1}
4574152e677Sdanielk1977}
4583e355807Sdrh
4593e355807Sdrh# Variations on the order of terms in a WHERE clause in order
4603e355807Sdrh# to make sure the OR optimizer can recognize them all.
4613e355807Sdrhdo_test where2-6.20 {
4623e355807Sdrh  queryplan {
463165674d8Sdrh    SELECT x.a, y.a FROM t2249a x CROSS JOIN t2249a y WHERE x.a=y.a
4643e355807Sdrh  }
4654fe425adSdrh} {0123 0123 nosort x sqlite_autoindex_t2249a_1 y sqlite_autoindex_t2249a_1}
466284f4acaSdanielk1977ifcapable explain&&subquery {
467284f4acaSdanielk1977  # These tests are not run if subquery support is not included in the
468284f4acaSdanielk1977  # build. This is because these tests test the "a = 1 OR a = 2" to
469284f4acaSdanielk1977  # "a IN (1, 2)" optimisation transformation, which is not enabled if
470284f4acaSdanielk1977  # subqueries and the IN operator is not available.
471284f4acaSdanielk1977  #
4723e355807Sdrh  do_test where2-6.21 {
4733e355807Sdrh    queryplan {
474165674d8Sdrh      SELECT x.a,y.a FROM t2249a x CROSS JOIN t2249a y
475165674d8Sdrh       WHERE x.a=y.a OR y.a='hello'
4763e355807Sdrh    }
4774fe425adSdrh  } {0123 0123 nosort x sqlite_autoindex_t2249a_1 y sqlite_autoindex_t2249a_1}
4783e355807Sdrh  do_test where2-6.22 {
4793e355807Sdrh    queryplan {
480165674d8Sdrh      SELECT x.a,y.a FROM t2249a x CROSS JOIN t2249a y
481165674d8Sdrh       WHERE y.a=x.a OR y.a='hello'
4823e355807Sdrh    }
4834fe425adSdrh  } {0123 0123 nosort x sqlite_autoindex_t2249a_1 y sqlite_autoindex_t2249a_1}
4843e355807Sdrh  do_test where2-6.23 {
4853e355807Sdrh    queryplan {
486165674d8Sdrh      SELECT x.a,y.a FROM t2249a x CROSS JOIN t2249a y
487165674d8Sdrh       WHERE y.a='hello' OR x.a=y.a
4883e355807Sdrh    }
4894fe425adSdrh  } {0123 0123 nosort x sqlite_autoindex_t2249a_1 y sqlite_autoindex_t2249a_1}
4904152e677Sdanielk1977}
4913e355807Sdrh
4928718f526Sdrh# Unique queries (queries that are guaranteed to return only a single
4938718f526Sdrh# row of result) do not call the sorter.  But all tables must give
4948718f526Sdrh# a unique result.  If any one table in the join does not give a unique
4958718f526Sdrh# result then sorting is necessary.
4968718f526Sdrh#
4978718f526Sdrhdo_test where2-7.1 {
4988718f526Sdrh  cksort {
4998718f526Sdrh    create table t8(a unique, b, c);
5008718f526Sdrh    insert into t8 values(1,2,3);
5018718f526Sdrh    insert into t8 values(2,3,4);
5028718f526Sdrh    create table t9(x,y);
5038718f526Sdrh    insert into t9 values(2,4);
5048718f526Sdrh    insert into t9 values(2,3);
5058718f526Sdrh    select y from t8, t9 where a=1 order by a, y;
5068718f526Sdrh  }
5078718f526Sdrh} {3 4 sort}
5088718f526Sdrhdo_test where2-7.2 {
5098718f526Sdrh  cksort {
5108718f526Sdrh    select * from t8 where a=1 order by b, c
5118718f526Sdrh  }
5128718f526Sdrh} {1 2 3 nosort}
5138718f526Sdrhdo_test where2-7.3 {
5148718f526Sdrh  cksort {
5158718f526Sdrh    select * from t8, t9 where a=1 and y=3 order by b, x
5168718f526Sdrh  }
5178718f526Sdrh} {1 2 3 2 3 sort}
5188718f526Sdrhdo_test where2-7.4 {
5198718f526Sdrh  cksort {
5208718f526Sdrh    create unique index i9y on t9(y);
5218718f526Sdrh    select * from t8, t9 where a=1 and y=3 order by b, x
5228718f526Sdrh  }
5238718f526Sdrh} {1 2 3 2 3 nosort}
524a611040eSdrh
525c1f19f95Sdan} ;# if {[permutation] != "no_optimization"}
526c1f19f95Sdan
527ffe0f890Sdrh# Ticket #1807.  Using IN constrains on multiple columns of
528ffe0f890Sdrh# a multi-column index.
529ffe0f890Sdrh#
530ffe0f890Sdrhifcapable subquery {
531ffe0f890Sdrh  do_test where2-8.1 {
532ffe0f890Sdrh    execsql {
533ffe0f890Sdrh      SELECT * FROM t1 WHERE x IN (20,21) AND y IN (1,2)
534ffe0f890Sdrh    }
535ffe0f890Sdrh  } {}
536ffe0f890Sdrh  do_test where2-8.2 {
537ffe0f890Sdrh    execsql {
538ffe0f890Sdrh      SELECT * FROM t1 WHERE x IN (1,2) AND y IN (-5,-6)
539ffe0f890Sdrh    }
540ffe0f890Sdrh  } {}
541ffe0f890Sdrh  execsql {CREATE TABLE tx AS SELECT * FROM t1}
542ffe0f890Sdrh  do_test where2-8.3 {
543ffe0f890Sdrh    execsql {
544ffe0f890Sdrh      SELECT w FROM t1
545ffe0f890Sdrh       WHERE x IN (SELECT x FROM tx WHERE rowid<0)
546ffe0f890Sdrh         AND +y IN (SELECT y FROM tx WHERE rowid=1)
547ffe0f890Sdrh    }
548ffe0f890Sdrh  } {}
549ffe0f890Sdrh  do_test where2-8.4 {
550ffe0f890Sdrh    execsql {
551ffe0f890Sdrh      SELECT w FROM t1
552ffe0f890Sdrh       WHERE x IN (SELECT x FROM tx WHERE rowid=1)
553ffe0f890Sdrh         AND y IN (SELECT y FROM tx WHERE rowid<0)
554ffe0f890Sdrh    }
555ffe0f890Sdrh  } {}
556ffe0f890Sdrh  #set sqlite_where_trace 1
557ffe0f890Sdrh  do_test where2-8.5 {
558ffe0f890Sdrh    execsql {
559ffe0f890Sdrh      CREATE INDEX tx_xyz ON tx(x, y, z, w);
560ffe0f890Sdrh      SELECT w FROM tx
561ffe0f890Sdrh       WHERE x IN (SELECT x FROM t1 WHERE w BETWEEN 10 AND 20)
562ffe0f890Sdrh         AND y IN (SELECT y FROM t1 WHERE w BETWEEN 10 AND 20)
563ffe0f890Sdrh         AND z IN (SELECT z FROM t1 WHERE w BETWEEN 12 AND 14)
564ffe0f890Sdrh    }
565ffe0f890Sdrh  } {12 13 14}
566ffe0f890Sdrh  do_test where2-8.6 {
567ffe0f890Sdrh    execsql {
568ffe0f890Sdrh      SELECT w FROM tx
569ffe0f890Sdrh       WHERE x IN (SELECT x FROM t1 WHERE w BETWEEN 10 AND 20)
570ffe0f890Sdrh         AND y IN (SELECT y FROM t1 WHERE w BETWEEN 12 AND 14)
571ffe0f890Sdrh         AND z IN (SELECT z FROM t1 WHERE w BETWEEN 10 AND 20)
572ffe0f890Sdrh    }
573ffe0f890Sdrh  } {12 13 14}
574ffe0f890Sdrh  do_test where2-8.7 {
575ffe0f890Sdrh    execsql {
576ffe0f890Sdrh      SELECT w FROM tx
577ffe0f890Sdrh       WHERE x IN (SELECT x FROM t1 WHERE w BETWEEN 12 AND 14)
578ffe0f890Sdrh         AND y IN (SELECT y FROM t1 WHERE w BETWEEN 10 AND 20)
579ffe0f890Sdrh         AND z IN (SELECT z FROM t1 WHERE w BETWEEN 10 AND 20)
580ffe0f890Sdrh    }
581ffe0f890Sdrh  } {10 11 12 13 14 15}
582ffe0f890Sdrh  do_test where2-8.8 {
583ffe0f890Sdrh    execsql {
584ffe0f890Sdrh      SELECT w FROM tx
585ffe0f890Sdrh       WHERE x IN (SELECT x FROM t1 WHERE w BETWEEN 10 AND 20)
586ffe0f890Sdrh         AND y IN (SELECT y FROM t1 WHERE w BETWEEN 10 AND 20)
587ffe0f890Sdrh         AND z IN (SELECT z FROM t1 WHERE w BETWEEN 10 AND 20)
588ffe0f890Sdrh    }
589ffe0f890Sdrh  } {10 11 12 13 14 15 16 17 18 19 20}
590ffe0f890Sdrh  do_test where2-8.9 {
591ffe0f890Sdrh    execsql {
592ffe0f890Sdrh      SELECT w FROM tx
593ffe0f890Sdrh       WHERE x IN (SELECT x FROM t1 WHERE w BETWEEN 10 AND 20)
594ffe0f890Sdrh         AND y IN (SELECT y FROM t1 WHERE w BETWEEN 10 AND 20)
595ffe0f890Sdrh         AND z IN (SELECT z FROM t1 WHERE w BETWEEN 2 AND 4)
596ffe0f890Sdrh    }
597ffe0f890Sdrh  } {}
598ffe0f890Sdrh  do_test where2-8.10 {
599ffe0f890Sdrh    execsql {
600ffe0f890Sdrh      SELECT w FROM tx
601ffe0f890Sdrh       WHERE x IN (SELECT x FROM t1 WHERE w BETWEEN 10 AND 20)
602ffe0f890Sdrh         AND y IN (SELECT y FROM t1 WHERE w BETWEEN 2 AND 4)
603ffe0f890Sdrh         AND z IN (SELECT z FROM t1 WHERE w BETWEEN 10 AND 20)
604ffe0f890Sdrh    }
605ffe0f890Sdrh  } {}
606ffe0f890Sdrh  do_test where2-8.11 {
607ffe0f890Sdrh    execsql {
608ffe0f890Sdrh      SELECT w FROM tx
609ffe0f890Sdrh       WHERE x IN (SELECT x FROM t1 WHERE w BETWEEN 2 AND 4)
610ffe0f890Sdrh         AND y IN (SELECT y FROM t1 WHERE w BETWEEN 10 AND 20)
611ffe0f890Sdrh         AND z IN (SELECT z FROM t1 WHERE w BETWEEN 10 AND 20)
612ffe0f890Sdrh    }
613ffe0f890Sdrh  } {}
614ffe0f890Sdrh  do_test where2-8.12 {
615ffe0f890Sdrh    execsql {
616ffe0f890Sdrh      SELECT w FROM tx
617ffe0f890Sdrh       WHERE x IN (SELECT x FROM t1 WHERE w BETWEEN 10 AND 20)
618ffe0f890Sdrh         AND y IN (SELECT y FROM t1 WHERE w BETWEEN 10 AND 20)
619ffe0f890Sdrh         AND z IN (SELECT z FROM t1 WHERE w BETWEEN -4 AND -2)
620ffe0f890Sdrh    }
621ffe0f890Sdrh  } {}
622ffe0f890Sdrh  do_test where2-8.13 {
623ffe0f890Sdrh    execsql {
624ffe0f890Sdrh      SELECT w FROM tx
625ffe0f890Sdrh       WHERE x IN (SELECT x FROM t1 WHERE w BETWEEN 10 AND 20)
626ffe0f890Sdrh         AND y IN (SELECT y FROM t1 WHERE w BETWEEN -4 AND -2)
627ffe0f890Sdrh         AND z IN (SELECT z FROM t1 WHERE w BETWEEN 10 AND 20)
628ffe0f890Sdrh    }
629ffe0f890Sdrh  } {}
630ffe0f890Sdrh  do_test where2-8.14 {
631ffe0f890Sdrh    execsql {
632ffe0f890Sdrh      SELECT w FROM tx
633ffe0f890Sdrh       WHERE x IN (SELECT x FROM t1 WHERE w BETWEEN -4 AND -2)
634ffe0f890Sdrh         AND y IN (SELECT y FROM t1 WHERE w BETWEEN 10 AND 20)
635ffe0f890Sdrh         AND z IN (SELECT z FROM t1 WHERE w BETWEEN 10 AND 20)
636ffe0f890Sdrh    }
637ffe0f890Sdrh  } {}
638ffe0f890Sdrh  do_test where2-8.15 {
639ffe0f890Sdrh    execsql {
640ffe0f890Sdrh      SELECT w FROM tx
641ffe0f890Sdrh       WHERE x IN (SELECT x FROM t1 WHERE w BETWEEN 10 AND 20)
642ffe0f890Sdrh         AND y IN (SELECT y FROM t1 WHERE w BETWEEN 10 AND 20)
643ffe0f890Sdrh         AND z IN (SELECT z FROM t1 WHERE w BETWEEN 200 AND 300)
644ffe0f890Sdrh    }
645ffe0f890Sdrh  } {}
646ffe0f890Sdrh  do_test where2-8.16 {
647ffe0f890Sdrh    execsql {
648ffe0f890Sdrh      SELECT w FROM tx
649ffe0f890Sdrh       WHERE x IN (SELECT x FROM t1 WHERE w BETWEEN 10 AND 20)
650ffe0f890Sdrh         AND y IN (SELECT y FROM t1 WHERE w BETWEEN 200 AND 300)
651ffe0f890Sdrh         AND z IN (SELECT z FROM t1 WHERE w BETWEEN 10 AND 20)
652ffe0f890Sdrh    }
653ffe0f890Sdrh  } {}
654ffe0f890Sdrh  do_test where2-8.17 {
655ffe0f890Sdrh    execsql {
656ffe0f890Sdrh      SELECT w FROM tx
657ffe0f890Sdrh       WHERE x IN (SELECT x FROM t1 WHERE w BETWEEN 200 AND 300)
658ffe0f890Sdrh         AND y IN (SELECT y FROM t1 WHERE w BETWEEN 10 AND 20)
659ffe0f890Sdrh         AND z IN (SELECT z FROM t1 WHERE w BETWEEN 10 AND 20)
660ffe0f890Sdrh    }
661ffe0f890Sdrh  } {}
662ffe0f890Sdrh  do_test where2-8.18 {
663ffe0f890Sdrh    execsql {
664ffe0f890Sdrh      SELECT w FROM tx
665ffe0f890Sdrh       WHERE x IN (SELECT x FROM t1 WHERE +w BETWEEN 10 AND 20)
666ffe0f890Sdrh         AND y IN (SELECT y FROM t1 WHERE +w BETWEEN 10 AND 20)
667ffe0f890Sdrh         AND z IN (SELECT z FROM t1 WHERE +w BETWEEN 200 AND 300)
668ffe0f890Sdrh    }
669ffe0f890Sdrh  } {}
670ffe0f890Sdrh  do_test where2-8.19 {
671ffe0f890Sdrh    execsql {
672ffe0f890Sdrh      SELECT w FROM tx
673ffe0f890Sdrh       WHERE x IN (SELECT x FROM t1 WHERE +w BETWEEN 10 AND 20)
674ffe0f890Sdrh         AND y IN (SELECT y FROM t1 WHERE +w BETWEEN 200 AND 300)
675ffe0f890Sdrh         AND z IN (SELECT z FROM t1 WHERE +w BETWEEN 10 AND 20)
676ffe0f890Sdrh    }
677ffe0f890Sdrh  } {}
678ffe0f890Sdrh  do_test where2-8.20 {
679ffe0f890Sdrh    execsql {
680ffe0f890Sdrh      SELECT w FROM tx
681ffe0f890Sdrh       WHERE x IN (SELECT x FROM t1 WHERE +w BETWEEN 200 AND 300)
682ffe0f890Sdrh         AND y IN (SELECT y FROM t1 WHERE +w BETWEEN 10 AND 20)
683ffe0f890Sdrh         AND z IN (SELECT z FROM t1 WHERE +w BETWEEN 10 AND 20)
684ffe0f890Sdrh    }
685ffe0f890Sdrh  } {}
686ffe0f890Sdrh}
68738276586Sdrh
68838276586Sdrh# Make sure WHERE clauses of the form A=1 AND (B=2 OR B=3) are optimized
68938276586Sdrh# when we have an index on A and B.
69038276586Sdrh#
6914152e677Sdanielk1977ifcapable or_opt&&tclvar {
69238276586Sdrh  do_test where2-9.1 {
69338276586Sdrh    execsql {
69438276586Sdrh      BEGIN;
69538276586Sdrh      CREATE TABLE t10(a,b,c);
69638276586Sdrh      INSERT INTO t10 VALUES(1,1,1);
69738276586Sdrh      INSERT INTO t10 VALUES(1,2,2);
69838276586Sdrh      INSERT INTO t10 VALUES(1,3,3);
69938276586Sdrh    }
70038276586Sdrh    for {set i 4} {$i<=1000} {incr i} {
70138276586Sdrh      execsql {INSERT INTO t10 VALUES(1,$i,$i)}
70238276586Sdrh    }
70338276586Sdrh    execsql {
70438276586Sdrh      CREATE INDEX i10 ON t10(a,b);
70538276586Sdrh      COMMIT;
70638276586Sdrh      SELECT count(*) FROM t10;
70738276586Sdrh    }
70838276586Sdrh  } 1000
709284f4acaSdanielk1977  ifcapable subquery {
71038276586Sdrh    do_test where2-9.2 {
71138276586Sdrh      count {
71238276586Sdrh        SELECT * FROM t10 WHERE a=1 AND (b=2 OR b=3)
71338276586Sdrh      }
71438276586Sdrh    } {1 2 2 1 3 3 7}
71538276586Sdrh  }
716284f4acaSdanielk1977}
71738276586Sdrh
718be837bddSdrh# Indices with redundant columns
719be837bddSdrh#
720be837bddSdrhdo_test where2-11.1 {
721be837bddSdrh  execsql {
722be837bddSdrh    CREATE TABLE t11(a,b,c,d);
723be837bddSdrh    CREATE INDEX i11aba ON t11(a,b,a,c); -- column A occurs twice.
724be837bddSdrh    INSERT INTO t11 VALUES(1,2,3,4);
725be837bddSdrh    INSERT INTO t11 VALUES(5,6,7,8);
726be837bddSdrh    INSERT INTO t11 VALUES(1,2,9,10);
727be837bddSdrh    INSERT INTO t11 VALUES(5,11,12,13);
728be837bddSdrh    SELECT c FROM t11 WHERE a=1 AND b=2 ORDER BY c;
729be837bddSdrh  }
730be837bddSdrh} {3 9}
731be837bddSdrhdo_test where2-11.2 {
732be837bddSdrh  execsql {
733be837bddSdrh    CREATE INDEX i11cccccccc ON t11(c,c,c,c,c,c,c,c); -- repeated column
734be837bddSdrh    SELECT d FROM t11 WHERE c=9;
735be837bddSdrh  }
736be837bddSdrh} {10}
737be837bddSdrhdo_test where2-11.3 {
738be837bddSdrh  execsql {
739be837bddSdrh    SELECT d FROM t11 WHERE c IN (1,2,3,4,5);
740be837bddSdrh  }
741be837bddSdrh} {4}
742be837bddSdrhdo_test where2-11.4 {
743be837bddSdrh  execsql {
744be837bddSdrh    SELECT d FROM t11 WHERE c=7 OR (a=1 AND b=2) ORDER BY d;
745be837bddSdrh  }
746be837bddSdrh} {4 8 10}
747be837bddSdrh
748aa32e3c6Sdrh# Verify that the OR clause is used in an outer loop even when
749aa32e3c6Sdrh# the OR clause scores slightly better on an inner loop.
750c63e880bSdanif {[permutation] != "no_optimization"} {
751aa32e3c6Sdrhdo_execsql_test where2-12.1 {
752165674d8Sdrh  CREATE TABLE t12(x INTEGER PRIMARY KEY, y INT, z CHAR(100));
753aa32e3c6Sdrh  CREATE INDEX t12y ON t12(y);
754aa32e3c6Sdrh  EXPLAIN QUERY PLAN
755aa32e3c6Sdrh    SELECT a.x, b.x
756aa32e3c6Sdrh      FROM t12 AS a JOIN t12 AS b ON a.y=b.x
757aa32e3c6Sdrh     WHERE (b.x=$abc OR b.y=$abc);
758*8210233cSdrh} {/SEARCH b .*SEARCH b /}
759c63e880bSdan}
760aa32e3c6Sdrh
761a45fdc7bSdrh# Verify that all necessary OP_OpenRead opcodes occur in the OR optimization.
762a45fdc7bSdrh#
763a45fdc7bSdrhdo_execsql_test where2-13.1 {
764a45fdc7bSdrh  CREATE TABLE t13(a,b);
765a45fdc7bSdrh  CREATE INDEX t13a ON t13(a);
766a45fdc7bSdrh  INSERT INTO t13 VALUES(4,5);
767a45fdc7bSdrh  SELECT * FROM t13 WHERE (1=2 AND a=3) OR a=4;
768a45fdc7bSdrh} {4 5}
769be837bddSdrh
77090730c9eSdrh# https://www.sqlite.org/src/info/5e3c886796e5512e  (2016-03-09)
77190730c9eSdrh# Correlated subquery on the RHS of an IN operator
77290730c9eSdrh#
77390730c9eSdrhdo_execsql_test where2-14.1 {
77490730c9eSdrh  CREATE TABLE t14a(x INTEGER PRIMARY KEY);
77590730c9eSdrh  INSERT INTO t14a(x) VALUES(1),(2),(3),(4);
77690730c9eSdrh  CREATE TABLE t14b(y INTEGER PRIMARY KEY);
77790730c9eSdrh  INSERT INTO t14b(y) VALUES(1);
77890730c9eSdrh  SELECT x FROM t14a WHERE x NOT IN (SELECT x FROM t14b);
77990730c9eSdrh} {}
78090730c9eSdrh
781a611040eSdrhfinish_test
782