xref: /sqlite-3.40.0/test/where2.test (revision 85b623f2)
1# 2005 July 28
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# This file implements regression tests for SQLite library.  The
12# focus of this file is testing the use of indices in WHERE clauses
13# based on recent changes to the optimizer.
14#
15# $Id: where2.test,v 1.13 2007/12/10 05:03:48 danielk1977 Exp $
16
17set testdir [file dirname $argv0]
18source $testdir/tester.tcl
19
20# Build some test data
21#
22do_test where2-1.0 {
23  execsql {
24    BEGIN;
25    CREATE TABLE t1(w int, x int, y int, z int);
26  }
27  for {set i 1} {$i<=100} {incr i} {
28    set w $i
29    set x [expr {int(log($i)/log(2))}]
30    set y [expr {$i*$i + 2*$i + 1}]
31    set z [expr {$x+$y}]
32    ifcapable tclvar {
33      execsql {INSERT INTO t1 VALUES($::w,$::x,$::y,$::z)}
34    } else {
35      execsql {INSERT INTO t1 VALUES(:w,:x,:y,:z)}
36    }
37  }
38  execsql {
39    CREATE UNIQUE INDEX i1w ON t1(w);
40    CREATE INDEX i1xy ON t1(x,y);
41    CREATE INDEX i1zyx ON t1(z,y,x);
42    COMMIT;
43  }
44} {}
45
46# Do an SQL statement.  Append the search count to the end of the result.
47#
48proc count sql {
49  set ::sqlite_search_count 0
50  return [concat [execsql $sql] $::sqlite_search_count]
51}
52
53# This procedure executes the SQL.  Then it checks to see if the OP_Sort
54# opcode was executed.  If an OP_Sort did occur, then "sort" is appended
55# to the result.  If no OP_Sort happened, then "nosort" is appended.
56#
57# This procedure is used to check to make sure sorting is or is not
58# occurring as expected.
59#
60proc cksort {sql} {
61  set ::sqlite_sort_count 0
62  set data [execsql $sql]
63  if {$::sqlite_sort_count} {set x sort} {set x nosort}
64  lappend data $x
65  return $data
66}
67
68# This procedure executes the SQL.  Then it appends to the result the
69# "sort" or "nosort" keyword (as in the cksort procedure above) then
70# it appends the ::sqlite_query_plan variable.
71#
72proc queryplan {sql} {
73  set ::sqlite_sort_count 0
74  set data [execsql $sql]
75  if {$::sqlite_sort_count} {set x sort} {set x nosort}
76  lappend data $x
77  return [concat $data $::sqlite_query_plan]
78}
79
80
81# Prefer a UNIQUE index over another index.
82#
83do_test where2-1.1 {
84  queryplan {
85    SELECT * FROM t1 WHERE w=85 AND x=6 AND y=7396
86  }
87} {85 6 7396 7402 nosort t1 i1w}
88
89# Always prefer a rowid== constraint over any other index.
90#
91do_test where2-1.3 {
92  queryplan {
93    SELECT * FROM t1 WHERE w=85 AND x=6 AND y=7396 AND rowid=85
94  }
95} {85 6 7396 7402 nosort t1 *}
96
97# When constrained by a UNIQUE index, the ORDER BY clause is always ignored.
98#
99do_test where2-2.1 {
100  queryplan {
101    SELECT * FROM t1 WHERE w=85 ORDER BY random(5);
102  }
103} {85 6 7396 7402 nosort t1 i1w}
104do_test where2-2.2 {
105  queryplan {
106    SELECT * FROM t1 WHERE x=6 AND y=7396 ORDER BY random(5);
107  }
108} {85 6 7396 7402 sort t1 i1xy}
109do_test where2-2.3 {
110  queryplan {
111    SELECT * FROM t1 WHERE rowid=85 AND x=6 AND y=7396 ORDER BY random(5);
112  }
113} {85 6 7396 7402 nosort t1 *}
114
115
116# Efficient handling of forward and reverse table scans.
117#
118do_test where2-3.1 {
119  queryplan {
120    SELECT * FROM t1 ORDER BY rowid LIMIT 2
121  }
122} {1 0 4 4 2 1 9 10 nosort t1 *}
123do_test where2-3.2 {
124  queryplan {
125    SELECT * FROM t1 ORDER BY rowid DESC LIMIT 2
126  }
127} {100 6 10201 10207 99 6 10000 10006 nosort t1 *}
128
129# The IN operator can be used by indices at multiple layers
130#
131ifcapable subquery {
132  do_test where2-4.1 {
133    queryplan {
134      SELECT * FROM t1 WHERE z IN (10207,10006) AND y IN (10000,10201)
135                       AND x>0 AND x<10
136      ORDER BY w
137    }
138  } {99 6 10000 10006 100 6 10201 10207 sort t1 i1zyx}
139  do_test where2-4.2 {
140    queryplan {
141      SELECT * FROM t1 WHERE z IN (10207,10006) AND y=10000
142                       AND x>0 AND x<10
143      ORDER BY w
144    }
145  } {99 6 10000 10006 sort t1 i1zyx}
146  do_test where2-4.3 {
147    queryplan {
148      SELECT * FROM t1 WHERE z=10006 AND y IN (10000,10201)
149                       AND x>0 AND x<10
150      ORDER BY w
151    }
152  } {99 6 10000 10006 sort t1 i1zyx}
153  ifcapable compound {
154    do_test where2-4.4 {
155      queryplan {
156        SELECT * FROM t1 WHERE z IN (SELECT 10207 UNION SELECT 10006)
157                         AND y IN (10000,10201)
158                         AND x>0 AND x<10
159        ORDER BY w
160      }
161    } {99 6 10000 10006 100 6 10201 10207 sort t1 i1zyx}
162    do_test where2-4.5 {
163      queryplan {
164        SELECT * FROM t1 WHERE z IN (SELECT 10207 UNION SELECT 10006)
165                         AND y IN (SELECT 10000 UNION SELECT 10201)
166                         AND x>0 AND x<10
167        ORDER BY w
168      }
169    } {99 6 10000 10006 100 6 10201 10207 sort t1 i1zyx}
170  }
171  do_test where2-4.6 {
172    queryplan {
173      SELECT * FROM t1
174       WHERE x IN (1,2,3,4,5,6,7,8)
175         AND y IN (10000,10001,10002,10003,10004,10005)
176       ORDER BY 2
177    }
178  } {99 6 10000 10006 sort t1 i1xy}
179
180  # Duplicate entires on the RHS of an IN operator do not cause duplicate
181  # output rows.
182  #
183  do_test where2-4.6 {
184    queryplan {
185      SELECT * FROM t1 WHERE z IN (10207,10006,10006,10207)
186      ORDER BY w
187    }
188  } {99 6 10000 10006 100 6 10201 10207 sort t1 i1zyx}
189  ifcapable compound {
190    do_test where2-4.7 {
191      queryplan {
192        SELECT * FROM t1 WHERE z IN (
193           SELECT 10207 UNION ALL SELECT 10006
194           UNION ALL SELECT 10006 UNION ALL SELECT 10207)
195        ORDER BY w
196      }
197    } {99 6 10000 10006 100 6 10201 10207 sort t1 i1zyx}
198  }
199
200} ;# ifcapable subquery
201
202# The use of an IN operator disables the index as a sorter.
203#
204do_test where2-5.1 {
205  queryplan {
206    SELECT * FROM t1 WHERE w=99 ORDER BY w
207  }
208} {99 6 10000 10006 nosort t1 i1w}
209
210ifcapable subquery {
211  do_test where2-5.2 {
212    queryplan {
213      SELECT * FROM t1 WHERE w IN (99) ORDER BY w
214    }
215  } {99 6 10000 10006 sort t1 i1w}
216}
217
218# Verify that OR clauses get translated into IN operators.
219#
220set ::idx {}
221ifcapable subquery {set ::idx i1w}
222do_test where2-6.1.1 {
223  queryplan {
224    SELECT * FROM t1 WHERE w=99 OR w=100 ORDER BY +w
225  }
226} [list 99 6 10000 10006 100 6 10201 10207 sort t1 $::idx]
227do_test where2-6.1.2 {
228  queryplan {
229    SELECT * FROM t1 WHERE 99=w OR 100=w ORDER BY +w
230  }
231} [list 99 6 10000 10006 100 6 10201 10207 sort t1 $::idx]
232do_test where2-6.2 {
233  queryplan {
234    SELECT * FROM t1 WHERE w=99 OR w=100 OR 6=w ORDER BY +w
235  }
236} [list 6 2 49 51 99 6 10000 10006 100 6 10201 10207 sort t1 $::idx]
237
238do_test where2-6.3 {
239  queryplan {
240    SELECT * FROM t1 WHERE w=99 OR w=100 OR 6=+w ORDER BY +w
241  }
242} {6 2 49 51 99 6 10000 10006 100 6 10201 10207 sort t1 {}}
243do_test where2-6.4 {
244  queryplan {
245    SELECT * FROM t1 WHERE w=99 OR +w=100 OR 6=w ORDER BY +w
246  }
247} {6 2 49 51 99 6 10000 10006 100 6 10201 10207 sort t1 {}}
248
249set ::idx {}
250ifcapable subquery {set ::idx i1zyx}
251do_test where2-6.5 {
252  queryplan {
253    SELECT b.* FROM t1 a, t1 b
254     WHERE a.w=1 AND (a.y=b.z OR b.z=10)
255     ORDER BY +b.w
256  }
257} [list 1 0 4 4 2 1 9 10 sort a i1w b $::idx]
258do_test where2-6.6 {
259  queryplan {
260    SELECT b.* FROM t1 a, t1 b
261     WHERE a.w=1 AND (b.z=10 OR a.y=b.z OR b.z=10)
262     ORDER BY +b.w
263  }
264} [list 1 0 4 4 2 1 9 10 sort a i1w b $::idx]
265
266# Ticket #2249.  Make sure the OR optimization is not attempted if
267# comparisons between columns of different affinities are needed.
268#
269do_test where2-6.7 {
270  execsql {
271    CREATE TABLE t2249a(a TEXT UNIQUE);
272    CREATE TABLE t2249b(b INTEGER);
273    INSERT INTO t2249a VALUES('0123');
274    INSERT INTO t2249b VALUES(123);
275  }
276  queryplan {
277    -- Because a is type TEXT and b is type INTEGER, both a and b
278    -- will attempt to convert to NUMERIC before the comparison.
279    -- They will thus compare equal.
280    --
281    SELECT * FROM t2249b CROSS JOIN t2249a WHERE a=b;
282  }
283} {123 0123 nosort t2249b {} t2249a {}}
284do_test where2-6.9 {
285  queryplan {
286    -- The + operator removes affinity from the rhs.  No conversions
287    -- occur and the comparison is false.  The result is an empty set.
288    --
289    SELECT * FROM t2249b CROSS JOIN t2249a WHERE a=+b;
290  }
291} {nosort t2249b {} {} sqlite_autoindex_t2249a_1}
292do_test where2-6.9.2 {
293  # The same thing but with the expression flipped around.
294  queryplan {
295    SELECT * FROM t2249b CROSS JOIN t2249a WHERE +b=a
296  }
297} {nosort t2249b {} {} sqlite_autoindex_t2249a_1}
298do_test where2-6.10 {
299  queryplan {
300    -- Use + on both sides of the comparison to disable indices
301    -- completely.  Make sure we get the same result.
302    --
303    SELECT * FROM t2249b CROSS JOIN t2249a WHERE +a=+b;
304  }
305} {nosort t2249b {} t2249a {}}
306do_test where2-6.11 {
307  # This will not attempt the OR optimization because of the a=b
308  # comparison.
309  queryplan {
310    SELECT * FROM t2249b CROSS JOIN t2249a WHERE a=b OR a='hello';
311  }
312} {123 0123 nosort t2249b {} t2249a {}}
313do_test where2-6.11.2 {
314  # Permutations of the expression terms.
315  queryplan {
316    SELECT * FROM t2249b CROSS JOIN t2249a WHERE b=a OR a='hello';
317  }
318} {123 0123 nosort t2249b {} t2249a {}}
319do_test where2-6.11.3 {
320  # Permutations of the expression terms.
321  queryplan {
322    SELECT * FROM t2249b CROSS JOIN t2249a WHERE 'hello'=a OR b=a;
323  }
324} {123 0123 nosort t2249b {} t2249a {}}
325do_test where2-6.11.4 {
326  # Permutations of the expression terms.
327  queryplan {
328    SELECT * FROM t2249b CROSS JOIN t2249a WHERE a='hello' OR b=a;
329  }
330} {123 0123 nosort t2249b {} t2249a {}}
331ifcapable explain&&subquery {
332  # These tests are not run if subquery support is not included in the
333  # build. This is because these tests test the "a = 1 OR a = 2" to
334  # "a IN (1, 2)" optimisation transformation, which is not enabled if
335  # subqueries and the IN operator is not available.
336  #
337  do_test where2-6.12 {
338    # In this case, the +b disables the affinity conflict and allows
339    # the OR optimization to be used again.  The result is now an empty
340    # set, the same as in where2-6.9.
341    queryplan {
342      SELECT * FROM t2249b CROSS JOIN t2249a WHERE a=+b OR a='hello';
343    }
344  } {nosort t2249b {} {} sqlite_autoindex_t2249a_1}
345  do_test where2-6.12.2 {
346    # In this case, the +b disables the affinity conflict and allows
347    # the OR optimization to be used again.  The result is now an empty
348    # set, the same as in where2-6.9.
349    queryplan {
350      SELECT * FROM t2249b CROSS JOIN t2249a WHERE a='hello' OR +b=a;
351    }
352  } {nosort t2249b {} {} sqlite_autoindex_t2249a_1}
353  do_test where2-6.12.3 {
354    # In this case, the +b disables the affinity conflict and allows
355    # the OR optimization to be used again.  The result is now an empty
356    # set, the same as in where2-6.9.
357    queryplan {
358      SELECT * FROM t2249b CROSS JOIN t2249a WHERE +b=a OR a='hello';
359    }
360  } {nosort t2249b {} {} sqlite_autoindex_t2249a_1}
361  do_test where2-6.13 {
362    # The addition of +a on the second term disabled the OR optimization.
363    # But we should still get the same empty-set result as in where2-6.9.
364    queryplan {
365      SELECT * FROM t2249b CROSS JOIN t2249a WHERE a=+b OR +a='hello';
366    }
367  } {nosort t2249b {} t2249a {}}
368}
369
370# Variations on the order of terms in a WHERE clause in order
371# to make sure the OR optimizer can recognize them all.
372do_test where2-6.20 {
373  queryplan {
374    SELECT * FROM t2249a x CROSS JOIN t2249a y WHERE x.a=y.a
375  }
376} {0123 0123 nosort x {} {} sqlite_autoindex_t2249a_1}
377ifcapable explain&&subquery {
378  # These tests are not run if subquery support is not included in the
379  # build. This is because these tests test the "a = 1 OR a = 2" to
380  # "a IN (1, 2)" optimisation transformation, which is not enabled if
381  # subqueries and the IN operator is not available.
382  #
383  do_test where2-6.21 {
384    queryplan {
385      SELECT * FROM t2249a x CROSS JOIN t2249a y WHERE x.a=y.a OR y.a='hello'
386    }
387  } {0123 0123 nosort x {} {} sqlite_autoindex_t2249a_1}
388  do_test where2-6.22 {
389    queryplan {
390      SELECT * FROM t2249a x CROSS JOIN t2249a y WHERE y.a=x.a OR y.a='hello'
391    }
392  } {0123 0123 nosort x {} {} sqlite_autoindex_t2249a_1}
393  do_test where2-6.23 {
394    queryplan {
395      SELECT * FROM t2249a x CROSS JOIN t2249a y WHERE y.a='hello' OR x.a=y.a
396    }
397  } {0123 0123 nosort x {} {} sqlite_autoindex_t2249a_1}
398}
399
400# Unique queries (queries that are guaranteed to return only a single
401# row of result) do not call the sorter.  But all tables must give
402# a unique result.  If any one table in the join does not give a unique
403# result then sorting is necessary.
404#
405do_test where2-7.1 {
406  cksort {
407    create table t8(a unique, b, c);
408    insert into t8 values(1,2,3);
409    insert into t8 values(2,3,4);
410    create table t9(x,y);
411    insert into t9 values(2,4);
412    insert into t9 values(2,3);
413    select y from t8, t9 where a=1 order by a, y;
414  }
415} {3 4 sort}
416do_test where2-7.2 {
417  cksort {
418    select * from t8 where a=1 order by b, c
419  }
420} {1 2 3 nosort}
421do_test where2-7.3 {
422  cksort {
423    select * from t8, t9 where a=1 and y=3 order by b, x
424  }
425} {1 2 3 2 3 sort}
426do_test where2-7.4 {
427  cksort {
428    create unique index i9y on t9(y);
429    select * from t8, t9 where a=1 and y=3 order by b, x
430  }
431} {1 2 3 2 3 nosort}
432
433# Ticket #1807.  Using IN constrains on multiple columns of
434# a multi-column index.
435#
436ifcapable subquery {
437  do_test where2-8.1 {
438    execsql {
439      SELECT * FROM t1 WHERE x IN (20,21) AND y IN (1,2)
440    }
441  } {}
442  do_test where2-8.2 {
443    execsql {
444      SELECT * FROM t1 WHERE x IN (1,2) AND y IN (-5,-6)
445    }
446  } {}
447  execsql {CREATE TABLE tx AS SELECT * FROM t1}
448  do_test where2-8.3 {
449    execsql {
450      SELECT w FROM t1
451       WHERE x IN (SELECT x FROM tx WHERE rowid<0)
452         AND +y IN (SELECT y FROM tx WHERE rowid=1)
453    }
454  } {}
455  do_test where2-8.4 {
456    execsql {
457      SELECT w FROM t1
458       WHERE x IN (SELECT x FROM tx WHERE rowid=1)
459         AND y IN (SELECT y FROM tx WHERE rowid<0)
460    }
461  } {}
462  #set sqlite_where_trace 1
463  do_test where2-8.5 {
464    execsql {
465      CREATE INDEX tx_xyz ON tx(x, y, z, w);
466      SELECT w FROM tx
467       WHERE x IN (SELECT x FROM t1 WHERE w BETWEEN 10 AND 20)
468         AND y IN (SELECT y FROM t1 WHERE w BETWEEN 10 AND 20)
469         AND z IN (SELECT z FROM t1 WHERE w BETWEEN 12 AND 14)
470    }
471  } {12 13 14}
472  do_test where2-8.6 {
473    execsql {
474      SELECT w FROM tx
475       WHERE x IN (SELECT x FROM t1 WHERE w BETWEEN 10 AND 20)
476         AND y IN (SELECT y FROM t1 WHERE w BETWEEN 12 AND 14)
477         AND z IN (SELECT z FROM t1 WHERE w BETWEEN 10 AND 20)
478    }
479  } {12 13 14}
480  do_test where2-8.7 {
481    execsql {
482      SELECT w FROM tx
483       WHERE x IN (SELECT x FROM t1 WHERE w BETWEEN 12 AND 14)
484         AND y IN (SELECT y FROM t1 WHERE w BETWEEN 10 AND 20)
485         AND z IN (SELECT z FROM t1 WHERE w BETWEEN 10 AND 20)
486    }
487  } {10 11 12 13 14 15}
488  do_test where2-8.8 {
489    execsql {
490      SELECT w FROM tx
491       WHERE x IN (SELECT x FROM t1 WHERE w BETWEEN 10 AND 20)
492         AND y IN (SELECT y FROM t1 WHERE w BETWEEN 10 AND 20)
493         AND z IN (SELECT z FROM t1 WHERE w BETWEEN 10 AND 20)
494    }
495  } {10 11 12 13 14 15 16 17 18 19 20}
496  do_test where2-8.9 {
497    execsql {
498      SELECT w FROM tx
499       WHERE x IN (SELECT x FROM t1 WHERE w BETWEEN 10 AND 20)
500         AND y IN (SELECT y FROM t1 WHERE w BETWEEN 10 AND 20)
501         AND z IN (SELECT z FROM t1 WHERE w BETWEEN 2 AND 4)
502    }
503  } {}
504  do_test where2-8.10 {
505    execsql {
506      SELECT w FROM tx
507       WHERE x IN (SELECT x FROM t1 WHERE w BETWEEN 10 AND 20)
508         AND y IN (SELECT y FROM t1 WHERE w BETWEEN 2 AND 4)
509         AND z IN (SELECT z FROM t1 WHERE w BETWEEN 10 AND 20)
510    }
511  } {}
512  do_test where2-8.11 {
513    execsql {
514      SELECT w FROM tx
515       WHERE x IN (SELECT x FROM t1 WHERE w BETWEEN 2 AND 4)
516         AND y IN (SELECT y FROM t1 WHERE w BETWEEN 10 AND 20)
517         AND z IN (SELECT z FROM t1 WHERE w BETWEEN 10 AND 20)
518    }
519  } {}
520  do_test where2-8.12 {
521    execsql {
522      SELECT w FROM tx
523       WHERE x IN (SELECT x FROM t1 WHERE w BETWEEN 10 AND 20)
524         AND y IN (SELECT y FROM t1 WHERE w BETWEEN 10 AND 20)
525         AND z IN (SELECT z FROM t1 WHERE w BETWEEN -4 AND -2)
526    }
527  } {}
528  do_test where2-8.13 {
529    execsql {
530      SELECT w FROM tx
531       WHERE x IN (SELECT x FROM t1 WHERE w BETWEEN 10 AND 20)
532         AND y IN (SELECT y FROM t1 WHERE w BETWEEN -4 AND -2)
533         AND z IN (SELECT z FROM t1 WHERE w BETWEEN 10 AND 20)
534    }
535  } {}
536  do_test where2-8.14 {
537    execsql {
538      SELECT w FROM tx
539       WHERE x IN (SELECT x FROM t1 WHERE w BETWEEN -4 AND -2)
540         AND y IN (SELECT y FROM t1 WHERE w BETWEEN 10 AND 20)
541         AND z IN (SELECT z FROM t1 WHERE w BETWEEN 10 AND 20)
542    }
543  } {}
544  do_test where2-8.15 {
545    execsql {
546      SELECT w FROM tx
547       WHERE x IN (SELECT x FROM t1 WHERE w BETWEEN 10 AND 20)
548         AND y IN (SELECT y FROM t1 WHERE w BETWEEN 10 AND 20)
549         AND z IN (SELECT z FROM t1 WHERE w BETWEEN 200 AND 300)
550    }
551  } {}
552  do_test where2-8.16 {
553    execsql {
554      SELECT w FROM tx
555       WHERE x IN (SELECT x FROM t1 WHERE w BETWEEN 10 AND 20)
556         AND y IN (SELECT y FROM t1 WHERE w BETWEEN 200 AND 300)
557         AND z IN (SELECT z FROM t1 WHERE w BETWEEN 10 AND 20)
558    }
559  } {}
560  do_test where2-8.17 {
561    execsql {
562      SELECT w FROM tx
563       WHERE x IN (SELECT x FROM t1 WHERE w BETWEEN 200 AND 300)
564         AND y IN (SELECT y FROM t1 WHERE w BETWEEN 10 AND 20)
565         AND z IN (SELECT z FROM t1 WHERE w BETWEEN 10 AND 20)
566    }
567  } {}
568  do_test where2-8.18 {
569    execsql {
570      SELECT w FROM tx
571       WHERE x IN (SELECT x FROM t1 WHERE +w BETWEEN 10 AND 20)
572         AND y IN (SELECT y FROM t1 WHERE +w BETWEEN 10 AND 20)
573         AND z IN (SELECT z FROM t1 WHERE +w BETWEEN 200 AND 300)
574    }
575  } {}
576  do_test where2-8.19 {
577    execsql {
578      SELECT w FROM tx
579       WHERE x IN (SELECT x FROM t1 WHERE +w BETWEEN 10 AND 20)
580         AND y IN (SELECT y FROM t1 WHERE +w BETWEEN 200 AND 300)
581         AND z IN (SELECT z FROM t1 WHERE +w BETWEEN 10 AND 20)
582    }
583  } {}
584  do_test where2-8.20 {
585    execsql {
586      SELECT w FROM tx
587       WHERE x IN (SELECT x FROM t1 WHERE +w BETWEEN 200 AND 300)
588         AND y IN (SELECT y FROM t1 WHERE +w BETWEEN 10 AND 20)
589         AND z IN (SELECT z FROM t1 WHERE +w BETWEEN 10 AND 20)
590    }
591  } {}
592}
593
594# Make sure WHERE clauses of the form A=1 AND (B=2 OR B=3) are optimized
595# when we have an index on A and B.
596#
597ifcapable or_opt&&tclvar {
598  do_test where2-9.1 {
599    execsql {
600      BEGIN;
601      CREATE TABLE t10(a,b,c);
602      INSERT INTO t10 VALUES(1,1,1);
603      INSERT INTO t10 VALUES(1,2,2);
604      INSERT INTO t10 VALUES(1,3,3);
605    }
606    for {set i 4} {$i<=1000} {incr i} {
607      execsql {INSERT INTO t10 VALUES(1,$i,$i)}
608    }
609    execsql {
610      CREATE INDEX i10 ON t10(a,b);
611      COMMIT;
612      SELECT count(*) FROM t10;
613    }
614  } 1000
615  ifcapable subquery {
616    do_test where2-9.2 {
617      count {
618        SELECT * FROM t10 WHERE a=1 AND (b=2 OR b=3)
619      }
620    } {1 2 2 1 3 3 7}
621  }
622}
623
624finish_test
625