xref: /sqlite-3.40.0/test/where.test (revision 85b623f2)
1# 4 2001 September 15
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 clases.
13#
14# $Id: where.test,v 1.44 2007/11/29 17:43:28 danielk1977 Exp $
15
16set testdir [file dirname $argv0]
17source $testdir/tester.tcl
18
19# Build some test data
20#
21do_test where-1.0 {
22  execsql {
23    CREATE TABLE t1(w int, x int, y int);
24    CREATE TABLE t2(p int, q int, r int, s int);
25  }
26  for {set i 1} {$i<=100} {incr i} {
27    set w $i
28    set x [expr {int(log($i)/log(2))}]
29    set y [expr {$i*$i + 2*$i + 1}]
30    execsql "INSERT INTO t1 VALUES($w,$x,$y)"
31  }
32
33  ifcapable subquery {
34    execsql {
35      INSERT INTO t2 SELECT 101-w, x, (SELECT max(y) FROM t1)+1-y, y FROM t1;
36    }
37  } else {
38    set maxy [execsql {select max(y) from t1}]
39    execsql "
40      INSERT INTO t2 SELECT 101-w, x, $maxy+1-y, y FROM t1;
41    "
42  }
43
44  execsql {
45    CREATE INDEX i1w ON t1(w);
46    CREATE INDEX i1xy ON t1(x,y);
47    CREATE INDEX i2p ON t2(p);
48    CREATE INDEX i2r ON t2(r);
49    CREATE INDEX i2qs ON t2(q, s);
50  }
51} {}
52
53# Do an SQL statement.  Append the search count to the end of the result.
54#
55proc count sql {
56  set ::sqlite_search_count 0
57  return [concat [execsql $sql] $::sqlite_search_count]
58}
59
60# Verify that queries use an index.  We are using the special variable
61# "sqlite_search_count" which tallys the number of executions of MoveTo
62# and Next operators in the VDBE.  By verifing that the search count is
63# small we can be assured that indices are being used properly.
64#
65do_test where-1.1.1 {
66  count {SELECT x, y, w FROM t1 WHERE w=10}
67} {3 121 10 3}
68do_test where-1.1.2 {
69  set sqlite_query_plan
70} {t1 i1w}
71do_test where-1.1.3 {
72  count {SELECT x, y, w AS abc FROM t1 WHERE abc=10}
73} {3 121 10 3}
74do_test where-1.1.4 {
75  set sqlite_query_plan
76} {t1 i1w}
77do_test where-1.2.1 {
78  count {SELECT x, y, w FROM t1 WHERE w=11}
79} {3 144 11 3}
80do_test where-1.2.2 {
81  count {SELECT x, y, w AS abc FROM t1 WHERE abc=11}
82} {3 144 11 3}
83do_test where-1.3.1 {
84  count {SELECT x, y, w AS abc FROM t1 WHERE 11=w}
85} {3 144 11 3}
86do_test where-1.3.2 {
87  count {SELECT x, y, w AS abc FROM t1 WHERE 11=abc}
88} {3 144 11 3}
89do_test where-1.4.1 {
90  count {SELECT w, x, y FROM t1 WHERE 11=w AND x>2}
91} {11 3 144 3}
92do_test where-1.4.2 {
93  set sqlite_query_plan
94} {t1 i1w}
95do_test where-1.4.3 {
96  count {SELECT w AS a, x AS b, y FROM t1 WHERE 11=a AND b>2}
97} {11 3 144 3}
98do_test where-1.4.4 {
99  set sqlite_query_plan
100} {t1 i1w}
101do_test where-1.5 {
102  count {SELECT x, y FROM t1 WHERE y<200 AND w=11 AND x>2}
103} {3 144 3}
104do_test where-1.5.2 {
105  set sqlite_query_plan
106} {t1 i1w}
107do_test where-1.6 {
108  count {SELECT x, y FROM t1 WHERE y<200 AND x>2 AND w=11}
109} {3 144 3}
110do_test where-1.7 {
111  count {SELECT x, y FROM t1 WHERE w=11 AND y<200 AND x>2}
112} {3 144 3}
113do_test where-1.8 {
114  count {SELECT x, y FROM t1 WHERE w>10 AND y=144 AND x=3}
115} {3 144 3}
116do_test where-1.8.2 {
117  set sqlite_query_plan
118} {t1 i1xy}
119do_test where-1.8.3 {
120  count {SELECT x, y FROM t1 WHERE y=144 AND x=3}
121  set sqlite_query_plan
122} {{} i1xy}
123do_test where-1.9 {
124  count {SELECT x, y FROM t1 WHERE y=144 AND w>10 AND x=3}
125} {3 144 3}
126do_test where-1.10 {
127  count {SELECT x, y FROM t1 WHERE x=3 AND w>=10 AND y=121}
128} {3 121 3}
129do_test where-1.11 {
130  count {SELECT x, y FROM t1 WHERE x=3 AND y=100 AND w<10}
131} {3 100 3}
132
133# New for SQLite version 2.1: Verify that that inequality constraints
134# are used correctly.
135#
136do_test where-1.12 {
137  count {SELECT w FROM t1 WHERE x=3 AND y<100}
138} {8 3}
139do_test where-1.13 {
140  count {SELECT w FROM t1 WHERE x=3 AND 100>y}
141} {8 3}
142do_test where-1.14 {
143  count {SELECT w FROM t1 WHERE 3=x AND y<100}
144} {8 3}
145do_test where-1.15 {
146  count {SELECT w FROM t1 WHERE 3=x AND 100>y}
147} {8 3}
148do_test where-1.16 {
149  count {SELECT w FROM t1 WHERE x=3 AND y<=100}
150} {8 9 5}
151do_test where-1.17 {
152  count {SELECT w FROM t1 WHERE x=3 AND 100>=y}
153} {8 9 5}
154do_test where-1.18 {
155  count {SELECT w FROM t1 WHERE x=3 AND y>225}
156} {15 3}
157do_test where-1.19 {
158  count {SELECT w FROM t1 WHERE x=3 AND 225<y}
159} {15 3}
160do_test where-1.20 {
161  count {SELECT w FROM t1 WHERE x=3 AND y>=225}
162} {14 15 5}
163do_test where-1.21 {
164  count {SELECT w FROM t1 WHERE x=3 AND 225<=y}
165} {14 15 5}
166do_test where-1.22 {
167  count {SELECT w FROM t1 WHERE x=3 AND y>121 AND y<196}
168} {11 12 5}
169do_test where-1.23 {
170  count {SELECT w FROM t1 WHERE x=3 AND y>=121 AND y<=196}
171} {10 11 12 13 9}
172do_test where-1.24 {
173  count {SELECT w FROM t1 WHERE x=3 AND 121<y AND 196>y}
174} {11 12 5}
175do_test where-1.25 {
176  count {SELECT w FROM t1 WHERE x=3 AND 121<=y AND 196>=y}
177} {10 11 12 13 9}
178
179# Need to work on optimizing the BETWEEN operator.
180#
181# do_test where-1.26 {
182#   count {SELECT w FROM t1 WHERE x=3 AND y BETWEEN 121 AND 196}
183# } {10 11 12 13 9}
184
185do_test where-1.27 {
186  count {SELECT w FROM t1 WHERE x=3 AND y+1==122}
187} {10 10}
188
189do_test where-1.28 {
190  count {SELECT w FROM t1 WHERE x+1=4 AND y+1==122}
191} {10 99}
192do_test where-1.29 {
193  count {SELECT w FROM t1 WHERE y==121}
194} {10 99}
195
196
197do_test where-1.30 {
198  count {SELECT w FROM t1 WHERE w>97}
199} {98 99 100 3}
200do_test where-1.31 {
201  count {SELECT w FROM t1 WHERE w>=97}
202} {97 98 99 100 4}
203do_test where-1.33 {
204  count {SELECT w FROM t1 WHERE w==97}
205} {97 2}
206do_test where-1.33.1  {
207  count {SELECT w FROM t1 WHERE w<=97 AND w==97}
208} {97 2}
209do_test where-1.33.2  {
210  count {SELECT w FROM t1 WHERE w<98 AND w==97}
211} {97 2}
212do_test where-1.33.3  {
213  count {SELECT w FROM t1 WHERE w>=97 AND w==97}
214} {97 2}
215do_test where-1.33.4  {
216  count {SELECT w FROM t1 WHERE w>96 AND w==97}
217} {97 2}
218do_test where-1.33.5  {
219  count {SELECT w FROM t1 WHERE w==97 AND w==97}
220} {97 2}
221do_test where-1.34 {
222  count {SELECT w FROM t1 WHERE w+1==98}
223} {97 99}
224do_test where-1.35 {
225  count {SELECT w FROM t1 WHERE w<3}
226} {1 2 2}
227do_test where-1.36 {
228  count {SELECT w FROM t1 WHERE w<=3}
229} {1 2 3 3}
230do_test where-1.37 {
231  count {SELECT w FROM t1 WHERE w+1<=4 ORDER BY w}
232} {1 2 3 99}
233
234do_test where-1.38 {
235  count {SELECT (w) FROM t1 WHERE (w)>(97)}
236} {98 99 100 3}
237do_test where-1.39 {
238  count {SELECT (w) FROM t1 WHERE (w)>=(97)}
239} {97 98 99 100 4}
240do_test where-1.40 {
241  count {SELECT (w) FROM t1 WHERE (w)==(97)}
242} {97 2}
243do_test where-1.41 {
244  count {SELECT (w) FROM t1 WHERE ((w)+(1))==(98)}
245} {97 99}
246
247
248# Do the same kind of thing except use a join as the data source.
249#
250do_test where-2.1 {
251  count {
252    SELECT w, p FROM t2, t1
253    WHERE x=q AND y=s AND r=8977
254  }
255} {34 67 6}
256do_test where-2.2 {
257  count {
258    SELECT w, p FROM t2, t1
259    WHERE x=q AND s=y AND r=8977
260  }
261} {34 67 6}
262do_test where-2.3 {
263  count {
264    SELECT w, p FROM t2, t1
265    WHERE x=q AND s=y AND r=8977 AND w>10
266  }
267} {34 67 6}
268do_test where-2.4 {
269  count {
270    SELECT w, p FROM t2, t1
271    WHERE p<80 AND x=q AND s=y AND r=8977 AND w>10
272  }
273} {34 67 6}
274do_test where-2.5 {
275  count {
276    SELECT w, p FROM t2, t1
277    WHERE p<80 AND x=q AND 8977=r AND s=y AND w>10
278  }
279} {34 67 6}
280do_test where-2.6 {
281  count {
282    SELECT w, p FROM t2, t1
283    WHERE x=q AND p=77 AND s=y AND w>5
284  }
285} {24 77 6}
286do_test where-2.7 {
287  count {
288    SELECT w, p FROM t1, t2
289    WHERE x=q AND p>77 AND s=y AND w=5
290  }
291} {5 96 6}
292
293# Lets do a 3-way join.
294#
295do_test where-3.1 {
296  count {
297    SELECT A.w, B.p, C.w FROM t1 as A, t2 as B, t1 as C
298    WHERE C.w=101-B.p AND B.r=10202-A.y AND A.w=11
299  }
300} {11 90 11 8}
301do_test where-3.2 {
302  count {
303    SELECT A.w, B.p, C.w FROM t1 as A, t2 as B, t1 as C
304    WHERE C.w=101-B.p AND B.r=10202-A.y AND A.w=12
305  }
306} {12 89 12 8}
307do_test where-3.3 {
308  count {
309    SELECT A.w, B.p, C.w FROM t1 as A, t2 as B, t1 as C
310    WHERE A.w=15 AND B.p=C.w AND B.r=10202-A.y
311  }
312} {15 86 86 8}
313
314# Test to see that the special case of a constant WHERE clause is
315# handled.
316#
317do_test where-4.1 {
318  count {
319    SELECT * FROM t1 WHERE 0
320  }
321} {0}
322do_test where-4.2 {
323  count {
324    SELECT * FROM t1 WHERE 1 LIMIT 1
325  }
326} {1 0 4 0}
327do_test where-4.3 {
328  execsql {
329    SELECT 99 WHERE 0
330  }
331} {}
332do_test where-4.4 {
333  execsql {
334    SELECT 99 WHERE 1
335  }
336} {99}
337do_test where-4.5 {
338  execsql {
339    SELECT 99 WHERE 0.1
340  }
341} {99}
342do_test where-4.6 {
343  execsql {
344    SELECT 99 WHERE 0.0
345  }
346} {}
347
348# Verify that IN operators in a WHERE clause are handled correctly.
349# Omit these tests if the build is not capable of sub-queries.
350#
351ifcapable subquery {
352  do_test where-5.1 {
353    count {
354      SELECT * FROM t1 WHERE rowid IN (1,2,3,1234) order by 1;
355    }
356  } {1 0 4 2 1 9 3 1 16 4}
357  do_test where-5.2 {
358    count {
359      SELECT * FROM t1 WHERE rowid+0 IN (1,2,3,1234) order by 1;
360    }
361  } {1 0 4 2 1 9 3 1 16 102}
362  do_test where-5.3 {
363    count {
364      SELECT * FROM t1 WHERE w IN (-1,1,2,3) order by 1;
365    }
366  } {1 0 4 2 1 9 3 1 16 14}
367  do_test where-5.4 {
368    count {
369      SELECT * FROM t1 WHERE w+0 IN (-1,1,2,3) order by 1;
370    }
371  } {1 0 4 2 1 9 3 1 16 102}
372  do_test where-5.5 {
373    count {
374      SELECT * FROM t1 WHERE rowid IN
375         (select rowid from t1 where rowid IN (-1,2,4))
376      ORDER BY 1;
377    }
378  } {2 1 9 4 2 25 3}
379  do_test where-5.6 {
380    count {
381      SELECT * FROM t1 WHERE rowid+0 IN
382         (select rowid from t1 where rowid IN (-1,2,4))
383      ORDER BY 1;
384    }
385  } {2 1 9 4 2 25 103}
386  do_test where-5.7 {
387    count {
388      SELECT * FROM t1 WHERE w IN
389         (select rowid from t1 where rowid IN (-1,2,4))
390      ORDER BY 1;
391    }
392  } {2 1 9 4 2 25 9}
393  do_test where-5.8 {
394    count {
395      SELECT * FROM t1 WHERE w+0 IN
396         (select rowid from t1 where rowid IN (-1,2,4))
397      ORDER BY 1;
398    }
399  } {2 1 9 4 2 25 103}
400  do_test where-5.9 {
401    count {
402      SELECT * FROM t1 WHERE x IN (1,7) ORDER BY 1;
403    }
404  } {2 1 9 3 1 16 7}
405  do_test where-5.10 {
406    count {
407      SELECT * FROM t1 WHERE x+0 IN (1,7) ORDER BY 1;
408    }
409  } {2 1 9 3 1 16 199}
410  do_test where-5.11 {
411    count {
412      SELECT * FROM t1 WHERE y IN (6400,8100) ORDER BY 1;
413    }
414  } {79 6 6400 89 6 8100 199}
415  do_test where-5.12 {
416    count {
417      SELECT * FROM t1 WHERE x=6 AND y IN (6400,8100) ORDER BY 1;
418    }
419  } {79 6 6400 89 6 8100 7}
420  do_test where-5.13 {
421    count {
422      SELECT * FROM t1 WHERE x IN (1,7) AND y NOT IN (6400,8100) ORDER BY 1;
423    }
424  } {2 1 9 3 1 16 7}
425  do_test where-5.14 {
426    count {
427      SELECT * FROM t1 WHERE x IN (1,7) AND y IN (9,10) ORDER BY 1;
428    }
429  } {2 1 9 8}
430  do_test where-5.15 {
431    count {
432      SELECT * FROM t1 WHERE x IN (1,7) AND y IN (9,16) ORDER BY 1;
433    }
434  } {2 1 9 3 1 16 11}
435}
436
437# This procedure executes the SQL.  Then it checks to see if the OP_Sort
438# opcode was executed.  If an OP_Sort did occur, then "sort" is appended
439# to the result.  If no OP_Sort happened, then "nosort" is appended.
440#
441# This procedure is used to check to make sure sorting is or is not
442# occurring as expected.
443#
444proc cksort {sql} {
445  set ::sqlite_sort_count 0
446  set data [execsql $sql]
447  if {$::sqlite_sort_count} {set x sort} {set x nosort}
448  lappend data $x
449  return $data
450}
451# Check out the logic that attempts to implement the ORDER BY clause
452# using an index rather than by sorting.
453#
454do_test where-6.1 {
455  execsql {
456    CREATE TABLE t3(a,b,c);
457    CREATE INDEX t3a ON t3(a);
458    CREATE INDEX t3bc ON t3(b,c);
459    CREATE INDEX t3acb ON t3(a,c,b);
460    INSERT INTO t3 SELECT w, 101-w, y FROM t1;
461    SELECT count(*), sum(a), sum(b), sum(c) FROM t3;
462  }
463} {100 5050 5050 348550}
464do_test where-6.2 {
465  cksort {
466    SELECT * FROM t3 ORDER BY a LIMIT 3
467  }
468} {1 100 4 2 99 9 3 98 16 nosort}
469do_test where-6.3 {
470  cksort {
471    SELECT * FROM t3 ORDER BY a+1 LIMIT 3
472  }
473} {1 100 4 2 99 9 3 98 16 sort}
474do_test where-6.4 {
475  cksort {
476    SELECT * FROM t3 WHERE a<10 ORDER BY a LIMIT 3
477  }
478} {1 100 4 2 99 9 3 98 16 nosort}
479do_test where-6.5 {
480  cksort {
481    SELECT * FROM t3 WHERE a>0 AND a<10 ORDER BY a LIMIT 3
482  }
483} {1 100 4 2 99 9 3 98 16 nosort}
484do_test where-6.6 {
485  cksort {
486    SELECT * FROM t3 WHERE a>0 ORDER BY a LIMIT 3
487  }
488} {1 100 4 2 99 9 3 98 16 nosort}
489do_test where-6.7 {
490  cksort {
491    SELECT * FROM t3 WHERE b>0 ORDER BY a LIMIT 3
492  }
493} {1 100 4 2 99 9 3 98 16 nosort}
494ifcapable subquery {
495  do_test where-6.8 {
496    cksort {
497      SELECT * FROM t3 WHERE a IN (3,5,7,1,9,4,2) ORDER BY a LIMIT 3
498    }
499  } {1 100 4 2 99 9 3 98 16 sort}
500}
501do_test where-6.9.1 {
502  cksort {
503    SELECT * FROM t3 WHERE a=1 AND c>0 ORDER BY a LIMIT 3
504  }
505} {1 100 4 nosort}
506do_test where-6.9.1.1 {
507  cksort {
508    SELECT * FROM t3 WHERE a>=1 AND a=1 AND c>0 ORDER BY a LIMIT 3
509  }
510} {1 100 4 nosort}
511do_test where-6.9.1.2 {
512  cksort {
513    SELECT * FROM t3 WHERE a<2 AND a=1 AND c>0 ORDER BY a LIMIT 3
514  }
515} {1 100 4 nosort}
516do_test where-6.9.2 {
517  cksort {
518    SELECT * FROM t3 WHERE a=1 AND c>0 ORDER BY a,c LIMIT 3
519  }
520} {1 100 4 nosort}
521do_test where-6.9.3 {
522  cksort {
523    SELECT * FROM t3 WHERE a=1 AND c>0 ORDER BY c LIMIT 3
524  }
525} {1 100 4 nosort}
526do_test where-6.9.4 {
527  cksort {
528    SELECT * FROM t3 WHERE a=1 AND c>0 ORDER BY a DESC LIMIT 3
529  }
530} {1 100 4 nosort}
531do_test where-6.9.5 {
532  cksort {
533    SELECT * FROM t3 WHERE a=1 AND c>0 ORDER BY a DESC, c DESC LIMIT 3
534  }
535} {1 100 4 nosort}
536do_test where-6.9.6 {
537  cksort {
538    SELECT * FROM t3 WHERE a=1 AND c>0 ORDER BY c DESC LIMIT 3
539  }
540} {1 100 4 nosort}
541do_test where-6.9.7 {
542  cksort {
543    SELECT * FROM t3 WHERE a=1 AND c>0 ORDER BY c,a LIMIT 3
544  }
545} {1 100 4 sort}
546do_test where-6.9.8 {
547  cksort {
548    SELECT * FROM t3 WHERE a=1 AND c>0 ORDER BY a DESC, c ASC LIMIT 3
549  }
550} {1 100 4 nosort}
551do_test where-6.9.9 {
552  cksort {
553    SELECT * FROM t3 WHERE a=1 AND c>0 ORDER BY a ASC, c DESC LIMIT 3
554  }
555} {1 100 4 nosort}
556do_test where-6.10 {
557  cksort {
558    SELECT * FROM t3 WHERE a=1 AND c>0 ORDER BY a LIMIT 3
559  }
560} {1 100 4 nosort}
561do_test where-6.11 {
562  cksort {
563    SELECT * FROM t3 WHERE a=1 AND c>0 ORDER BY a,c LIMIT 3
564  }
565} {1 100 4 nosort}
566do_test where-6.12 {
567  cksort {
568    SELECT * FROM t3 WHERE a=1 AND c>0 ORDER BY a,c,b LIMIT 3
569  }
570} {1 100 4 nosort}
571do_test where-6.13 {
572  cksort {
573    SELECT * FROM t3 WHERE a>0 ORDER BY a DESC LIMIT 3
574  }
575} {100 1 10201 99 2 10000 98 3 9801 nosort}
576do_test where-6.13.1 {
577  cksort {
578    SELECT * FROM t3 WHERE a>0 ORDER BY -a LIMIT 3
579  }
580} {100 1 10201 99 2 10000 98 3 9801 sort}
581do_test where-6.14 {
582  cksort {
583    SELECT * FROM t3 ORDER BY b LIMIT 3
584  }
585} {100 1 10201 99 2 10000 98 3 9801 nosort}
586do_test where-6.15 {
587  cksort {
588    SELECT t3.a, t1.x FROM t3, t1 WHERE t3.a=t1.w ORDER BY t3.a LIMIT 3
589  }
590} {1 0 2 1 3 1 nosort}
591do_test where-6.16 {
592  cksort {
593    SELECT t3.a, t1.x FROM t3, t1 WHERE t3.a=t1.w ORDER BY t1.x, t3.a LIMIT 3
594  }
595} {1 0 2 1 3 1 sort}
596do_test where-6.19 {
597  cksort {
598    SELECT y FROM t1 ORDER BY w LIMIT 3;
599  }
600} {4 9 16 nosort}
601do_test where-6.20 {
602  cksort {
603    SELECT y FROM t1 ORDER BY rowid LIMIT 3;
604  }
605} {4 9 16 nosort}
606do_test where-6.21 {
607  cksort {
608    SELECT y FROM t1 ORDER BY rowid, y LIMIT 3;
609  }
610} {4 9 16 nosort}
611do_test where-6.22 {
612  cksort {
613    SELECT y FROM t1 ORDER BY rowid, y DESC LIMIT 3;
614  }
615} {4 9 16 nosort}
616do_test where-6.23 {
617  cksort {
618    SELECT y FROM t1 WHERE y>4 ORDER BY rowid, w, x LIMIT 3;
619  }
620} {9 16 25 nosort}
621do_test where-6.24 {
622  cksort {
623    SELECT y FROM t1 WHERE y>=9 ORDER BY rowid, x DESC, w LIMIT 3;
624  }
625} {9 16 25 nosort}
626do_test where-6.25 {
627  cksort {
628    SELECT y FROM t1 WHERE y>4 AND y<25 ORDER BY rowid;
629  }
630} {9 16 nosort}
631do_test where-6.26 {
632  cksort {
633    SELECT y FROM t1 WHERE y>=4 AND y<=25 ORDER BY oid;
634  }
635} {4 9 16 25 nosort}
636do_test where-6.27 {
637  cksort {
638    SELECT y FROM t1 WHERE y<=25 ORDER BY _rowid_, w+y;
639  }
640} {4 9 16 25 nosort}
641
642
643# Tests for reverse-order sorting.
644#
645do_test where-7.1 {
646  cksort {
647    SELECT w FROM t1 WHERE x=3 ORDER BY y;
648  }
649} {8 9 10 11 12 13 14 15 nosort}
650do_test where-7.2 {
651  cksort {
652    SELECT w FROM t1 WHERE x=3 ORDER BY y DESC;
653  }
654} {15 14 13 12 11 10 9 8 nosort}
655do_test where-7.3 {
656  cksort {
657    SELECT w FROM t1 WHERE x=3 AND y>100 ORDER BY y LIMIT 3;
658  }
659} {10 11 12 nosort}
660do_test where-7.4 {
661  cksort {
662    SELECT w FROM t1 WHERE x=3 AND y>100 ORDER BY y DESC LIMIT 3;
663  }
664} {15 14 13 nosort}
665do_test where-7.5 {
666  cksort {
667    SELECT w FROM t1 WHERE x=3 AND y>121 ORDER BY y DESC;
668  }
669} {15 14 13 12 11 nosort}
670do_test where-7.6 {
671  cksort {
672    SELECT w FROM t1 WHERE x=3 AND y>=121 ORDER BY y DESC;
673  }
674} {15 14 13 12 11 10 nosort}
675do_test where-7.7 {
676  cksort {
677    SELECT w FROM t1 WHERE x=3 AND y>=121 AND y<196 ORDER BY y DESC;
678  }
679} {12 11 10 nosort}
680do_test where-7.8 {
681  cksort {
682    SELECT w FROM t1 WHERE x=3 AND y>=121 AND y<=196 ORDER BY y DESC;
683  }
684} {13 12 11 10 nosort}
685do_test where-7.9 {
686  cksort {
687    SELECT w FROM t1 WHERE x=3 AND y>121 AND y<=196 ORDER BY y DESC;
688  }
689} {13 12 11 nosort}
690do_test where-7.10 {
691  cksort {
692    SELECT w FROM t1 WHERE x=3 AND y>100 AND y<196 ORDER BY y DESC;
693  }
694} {12 11 10 nosort}
695do_test where-7.11 {
696  cksort {
697    SELECT w FROM t1 WHERE x=3 AND y>=121 AND y<196 ORDER BY y;
698  }
699} {10 11 12 nosort}
700do_test where-7.12 {
701  cksort {
702    SELECT w FROM t1 WHERE x=3 AND y>=121 AND y<=196 ORDER BY y;
703  }
704} {10 11 12 13 nosort}
705do_test where-7.13 {
706  cksort {
707    SELECT w FROM t1 WHERE x=3 AND y>121 AND y<=196 ORDER BY y;
708  }
709} {11 12 13 nosort}
710do_test where-7.14 {
711  cksort {
712    SELECT w FROM t1 WHERE x=3 AND y>100 AND y<196 ORDER BY y;
713  }
714} {10 11 12 nosort}
715do_test where-7.15 {
716  cksort {
717    SELECT w FROM t1 WHERE x=3 AND y<81 ORDER BY y;
718  }
719} {nosort}
720do_test where-7.16 {
721  cksort {
722    SELECT w FROM t1 WHERE x=3 AND y<=81 ORDER BY y;
723  }
724} {8 nosort}
725do_test where-7.17 {
726  cksort {
727    SELECT w FROM t1 WHERE x=3 AND y>256 ORDER BY y;
728  }
729} {nosort}
730do_test where-7.18 {
731  cksort {
732    SELECT w FROM t1 WHERE x=3 AND y>=256 ORDER BY y;
733  }
734} {15 nosort}
735do_test where-7.19 {
736  cksort {
737    SELECT w FROM t1 WHERE x=3 AND y<81 ORDER BY y DESC;
738  }
739} {nosort}
740do_test where-7.20 {
741  cksort {
742    SELECT w FROM t1 WHERE x=3 AND y<=81 ORDER BY y DESC;
743  }
744} {8 nosort}
745do_test where-7.21 {
746  cksort {
747    SELECT w FROM t1 WHERE x=3 AND y>256 ORDER BY y DESC;
748  }
749} {nosort}
750do_test where-7.22 {
751  cksort {
752    SELECT w FROM t1 WHERE x=3 AND y>=256 ORDER BY y DESC;
753  }
754} {15 nosort}
755do_test where-7.23 {
756  cksort {
757    SELECT w FROM t1 WHERE x=0 AND y<4 ORDER BY y;
758  }
759} {nosort}
760do_test where-7.24 {
761  cksort {
762    SELECT w FROM t1 WHERE x=0 AND y<=4 ORDER BY y;
763  }
764} {1 nosort}
765do_test where-7.25 {
766  cksort {
767    SELECT w FROM t1 WHERE x=6 AND y>10201 ORDER BY y;
768  }
769} {nosort}
770do_test where-7.26 {
771  cksort {
772    SELECT w FROM t1 WHERE x=6 AND y>=10201 ORDER BY y;
773  }
774} {100 nosort}
775do_test where-7.27 {
776  cksort {
777    SELECT w FROM t1 WHERE x=0 AND y<4 ORDER BY y DESC;
778  }
779} {nosort}
780do_test where-7.28 {
781  cksort {
782    SELECT w FROM t1 WHERE x=0 AND y<=4 ORDER BY y DESC;
783  }
784} {1 nosort}
785do_test where-7.29 {
786  cksort {
787    SELECT w FROM t1 WHERE x=6 AND y>10201 ORDER BY y DESC;
788  }
789} {nosort}
790do_test where-7.30 {
791  cksort {
792    SELECT w FROM t1 WHERE x=6 AND y>=10201 ORDER BY y DESC;
793  }
794} {100 nosort}
795do_test where-7.31 {
796  cksort {
797    SELECT y FROM t1 ORDER BY rowid DESC LIMIT 3
798  }
799} {10201 10000 9801 nosort}
800do_test where-7.32 {
801  cksort {
802    SELECT y FROM t1 WHERE y<25 ORDER BY rowid DESC
803  }
804} {16 9 4 nosort}
805do_test where-7.33 {
806  cksort {
807    SELECT y FROM t1 WHERE y<=25 ORDER BY rowid DESC
808  }
809} {25 16 9 4 nosort}
810do_test where-7.34 {
811  cksort {
812    SELECT y FROM t1 WHERE y<25 AND y>4 ORDER BY rowid DESC, y DESC
813  }
814} {16 9 nosort}
815do_test where-7.35 {
816  cksort {
817    SELECT y FROM t1 WHERE y<25 AND y>=4 ORDER BY rowid DESC
818  }
819} {16 9 4 nosort}
820
821do_test where-8.1 {
822  execsql {
823    CREATE TABLE t4 AS SELECT * FROM t1;
824    CREATE INDEX i4xy ON t4(x,y);
825  }
826  cksort {
827    SELECT w FROM t4 WHERE x=4 and y<1000 ORDER BY y DESC limit 3;
828  }
829} {30 29 28 nosort}
830do_test where-8.2 {
831  execsql {
832    DELETE FROM t4;
833  }
834  cksort {
835    SELECT w FROM t4 WHERE x=4 and y<1000 ORDER BY y DESC limit 3;
836  }
837} {nosort}
838
839# Make sure searches with an index work with an empty table.
840#
841do_test where-9.1 {
842  execsql {
843    CREATE TABLE t5(x PRIMARY KEY);
844    SELECT * FROM t5 WHERE x<10;
845  }
846} {}
847do_test where-9.2 {
848  execsql {
849    SELECT * FROM t5 WHERE x<10 ORDER BY x DESC;
850  }
851} {}
852do_test where-9.3 {
853  execsql {
854    SELECT * FROM t5 WHERE x=10;
855  }
856} {}
857
858do_test where-10.1 {
859  execsql {
860    SELECT 1 WHERE abs(random())<0
861  }
862} {}
863do_test where-10.2 {
864  proc tclvar_func {vname} {return [set ::$vname]}
865  db function tclvar tclvar_func
866  set ::v1 0
867  execsql {
868    SELECT count(*) FROM t1 WHERE tclvar('v1');
869  }
870} {0}
871do_test where-10.3 {
872  set ::v1 1
873  execsql {
874    SELECT count(*) FROM t1 WHERE tclvar('v1');
875  }
876} {100}
877do_test where-10.4 {
878  set ::v1 1
879  proc tclvar_func {vname} {
880    upvar #0 $vname v
881    set v [expr {!$v}]
882    return $v
883  }
884  execsql {
885    SELECT count(*) FROM t1 WHERE tclvar('v1');
886  }
887} {50}
888
889# Ticket #1376.  The query below was causing a segfault.
890# The problem was the age-old error of calling realloc() on an
891# array while there are still pointers to individual elements of
892# that array.
893#
894do_test where-11.1 {
895  execsql {
896   CREATE TABLE t99(Dte INT, X INT);
897   DELETE FROM t99 WHERE (Dte = 2451337) OR (Dte = 2451339) OR
898     (Dte BETWEEN 2451345 AND 2451347) OR (Dte = 2451351) OR
899     (Dte BETWEEN 2451355 AND 2451356) OR (Dte = 2451358) OR
900     (Dte = 2451362) OR (Dte = 2451365) OR (Dte = 2451367) OR
901     (Dte BETWEEN 2451372 AND 2451376) OR (Dte BETWEEN 2451382 AND 2451384) OR
902     (Dte = 2451387) OR (Dte BETWEEN 2451389 AND 2451391) OR
903     (Dte BETWEEN 2451393 AND 2451395) OR (Dte = 2451400) OR
904     (Dte = 2451402) OR (Dte = 2451404) OR (Dte BETWEEN 2451416 AND 2451418) OR
905     (Dte = 2451422) OR (Dte = 2451426) OR (Dte BETWEEN 2451445 AND 2451446) OR
906     (Dte = 2451456) OR (Dte = 2451458) OR (Dte BETWEEN 2451465 AND 2451467) OR
907     (Dte BETWEEN 2451469 AND 2451471) OR (Dte = 2451474) OR
908     (Dte BETWEEN 2451477 AND 2451501) OR (Dte BETWEEN 2451503 AND 2451509) OR
909     (Dte BETWEEN 2451511 AND 2451514) OR (Dte BETWEEN 2451518 AND 2451521) OR
910     (Dte BETWEEN 2451523 AND 2451531) OR (Dte BETWEEN 2451533 AND 2451537) OR
911     (Dte BETWEEN 2451539 AND 2451544) OR (Dte BETWEEN 2451546 AND 2451551) OR
912     (Dte BETWEEN 2451553 AND 2451555) OR (Dte = 2451557) OR
913     (Dte BETWEEN 2451559 AND 2451561) OR (Dte = 2451563) OR
914     (Dte BETWEEN 2451565 AND 2451566) OR (Dte BETWEEN 2451569 AND 2451571) OR
915     (Dte = 2451573) OR (Dte = 2451575) OR (Dte = 2451577) OR (Dte = 2451581) OR
916     (Dte BETWEEN 2451583 AND 2451586) OR (Dte BETWEEN 2451588 AND 2451592) OR
917     (Dte BETWEEN 2451596 AND 2451598) OR (Dte = 2451600) OR
918     (Dte BETWEEN 2451602 AND 2451603) OR (Dte = 2451606) OR (Dte = 2451611);
919  }
920} {}
921
922# Ticket #2116:  Make sure sorting by index works well with nn INTEGER PRIMARY
923# KEY.
924#
925do_test where-12.1 {
926  execsql {
927    CREATE TABLE t6(a INTEGER PRIMARY KEY, b TEXT);
928    INSERT INTO t6 VALUES(1,'one');
929    INSERT INTO t6 VALUES(4,'four');
930    CREATE INDEX t6i1 ON t6(b);
931  }
932  cksort {
933    SELECT * FROM t6 ORDER BY b;
934  }
935} {4 four 1 one nosort}
936do_test where-12.2 {
937  cksort {
938    SELECT * FROM t6 ORDER BY b, a;
939  }
940} {4 four 1 one nosort}
941do_test where-12.3 {
942  cksort {
943    SELECT * FROM t6 ORDER BY a;
944  }
945} {1 one 4 four nosort}
946do_test where-12.4 {
947  cksort {
948    SELECT * FROM t6 ORDER BY a, b;
949  }
950} {1 one 4 four nosort}
951do_test where-12.5 {
952  cksort {
953    SELECT * FROM t6 ORDER BY b DESC;
954  }
955} {1 one 4 four nosort}
956do_test where-12.6 {
957  cksort {
958    SELECT * FROM t6 ORDER BY b DESC, a DESC;
959  }
960} {1 one 4 four nosort}
961do_test where-12.7 {
962  cksort {
963    SELECT * FROM t6 ORDER BY b DESC, a ASC;
964  }
965} {1 one 4 four sort}
966do_test where-12.8 {
967  cksort {
968    SELECT * FROM t6 ORDER BY b ASC, a DESC;
969  }
970} {4 four 1 one sort}
971do_test where-12.9 {
972  cksort {
973    SELECT * FROM t6 ORDER BY a DESC;
974  }
975} {4 four 1 one nosort}
976do_test where-12.10 {
977  cksort {
978    SELECT * FROM t6 ORDER BY a DESC, b DESC;
979  }
980} {4 four 1 one nosort}
981do_test where-12.11 {
982  cksort {
983    SELECT * FROM t6 ORDER BY a DESC, b ASC;
984  }
985} {4 four 1 one nosort}
986do_test where-12.12 {
987  cksort {
988    SELECT * FROM t6 ORDER BY a ASC, b DESC;
989  }
990} {1 one 4 four nosort}
991do_test where-13.1 {
992  execsql {
993    CREATE TABLE t7(a INTEGER PRIMARY KEY, b TEXT);
994    INSERT INTO t7 VALUES(1,'one');
995    INSERT INTO t7 VALUES(4,'four');
996    CREATE INDEX t7i1 ON t7(b);
997  }
998  cksort {
999    SELECT * FROM t7 ORDER BY b;
1000  }
1001} {4 four 1 one nosort}
1002do_test where-13.2 {
1003  cksort {
1004    SELECT * FROM t7 ORDER BY b, a;
1005  }
1006} {4 four 1 one nosort}
1007do_test where-13.3 {
1008  cksort {
1009    SELECT * FROM t7 ORDER BY a;
1010  }
1011} {1 one 4 four nosort}
1012do_test where-13.4 {
1013  cksort {
1014    SELECT * FROM t7 ORDER BY a, b;
1015  }
1016} {1 one 4 four nosort}
1017do_test where-13.5 {
1018  cksort {
1019    SELECT * FROM t7 ORDER BY b DESC;
1020  }
1021} {1 one 4 four nosort}
1022do_test where-13.6 {
1023  cksort {
1024    SELECT * FROM t7 ORDER BY b DESC, a DESC;
1025  }
1026} {1 one 4 four nosort}
1027do_test where-13.7 {
1028  cksort {
1029    SELECT * FROM t7 ORDER BY b DESC, a ASC;
1030  }
1031} {1 one 4 four sort}
1032do_test where-13.8 {
1033  cksort {
1034    SELECT * FROM t7 ORDER BY b ASC, a DESC;
1035  }
1036} {4 four 1 one sort}
1037do_test where-13.9 {
1038  cksort {
1039    SELECT * FROM t7 ORDER BY a DESC;
1040  }
1041} {4 four 1 one nosort}
1042do_test where-13.10 {
1043  cksort {
1044    SELECT * FROM t7 ORDER BY a DESC, b DESC;
1045  }
1046} {4 four 1 one nosort}
1047do_test where-13.11 {
1048  cksort {
1049    SELECT * FROM t7 ORDER BY a DESC, b ASC;
1050  }
1051} {4 four 1 one nosort}
1052do_test where-13.12 {
1053  cksort {
1054    SELECT * FROM t7 ORDER BY a ASC, b DESC;
1055  }
1056} {1 one 4 four nosort}
1057
1058# Ticket #2211.
1059#
1060# When optimizing out ORDER BY clauses, make sure that trailing terms
1061# of the ORDER BY clause do not reference other tables in a join.
1062#
1063do_test where-14.1 {
1064  execsql {
1065    CREATE TABLE t8(a INTEGER PRIMARY KEY, b TEXT UNIQUE);
1066    INSERT INTO t8 VALUES(1,'one');
1067    INSERT INTO t8 VALUES(4,'four');
1068  }
1069  cksort {
1070    SELECT x.a || '/' || y.a FROM t8 x, t8 y ORDER BY x.a, y.b
1071  }
1072} {1/4 1/1 4/4 4/1 sort}
1073do_test where-14.2 {
1074  cksort {
1075    SELECT x.a || '/' || y.a FROM t8 x, t8 y ORDER BY x.a, y.b DESC
1076  }
1077} {1/1 1/4 4/1 4/4 sort}
1078do_test where-14.3 {
1079  cksort {
1080    SELECT x.a || '/' || y.a FROM t8 x, t8 y ORDER BY x.a, x.b
1081  }
1082} {1/1 1/4 4/1 4/4 nosort}
1083do_test where-14.4 {
1084  cksort {
1085    SELECT x.a || '/' || y.a FROM t8 x, t8 y ORDER BY x.a, x.b DESC
1086  }
1087} {1/1 1/4 4/1 4/4 nosort}
1088btree_breakpoint
1089do_test where-14.5 {
1090  cksort {
1091    SELECT x.a || '/' || y.a FROM t8 x, t8 y ORDER BY x.b, x.a||x.b
1092  }
1093} {4/1 4/4 1/1 1/4 nosort}
1094do_test where-14.6 {
1095  cksort {
1096    SELECT x.a || '/' || y.a FROM t8 x, t8 y ORDER BY x.b, x.a||x.b DESC
1097  }
1098} {4/1 4/4 1/1 1/4 nosort}
1099do_test where-14.7 {
1100  cksort {
1101    SELECT x.a || '/' || y.a FROM t8 x, t8 y ORDER BY x.b, y.a||y.b
1102  }
1103} {4/1 4/4 1/1 1/4 sort}
1104do_test where-14.7.1 {
1105  cksort {
1106    SELECT x.a || '/' || y.a FROM t8 x, t8 y ORDER BY x.b, x.a, y.a||y.b
1107  }
1108} {4/1 4/4 1/1 1/4 sort}
1109do_test where-14.7.2 {
1110  cksort {
1111    SELECT x.a || '/' || y.a FROM t8 x, t8 y ORDER BY x.b, x.a, x.a||x.b
1112  }
1113} {4/1 4/4 1/1 1/4 nosort}
1114do_test where-14.8 {
1115  cksort {
1116    SELECT x.a || '/' || y.a FROM t8 x, t8 y ORDER BY x.b, y.a||y.b DESC
1117  }
1118} {4/4 4/1 1/4 1/1 sort}
1119do_test where-14.9 {
1120  cksort {
1121    SELECT x.a || '/' || y.a FROM t8 x, t8 y ORDER BY x.b, x.a||y.b
1122  }
1123} {4/4 4/1 1/4 1/1 sort}
1124do_test where-14.10 {
1125  cksort {
1126    SELECT x.a || '/' || y.a FROM t8 x, t8 y ORDER BY x.b, x.a||y.b DESC
1127  }
1128} {4/1 4/4 1/1 1/4 sort}
1129do_test where-14.11 {
1130  cksort {
1131    SELECT x.a || '/' || y.a FROM t8 x, t8 y ORDER BY x.b, y.a||x.b
1132  }
1133} {4/1 4/4 1/1 1/4 sort}
1134do_test where-14.12 {
1135  cksort {
1136    SELECT x.a || '/' || y.a FROM t8 x, t8 y ORDER BY x.b, y.a||x.b DESC
1137  }
1138} {4/4 4/1 1/4 1/1 sort}
1139
1140# Ticket #2445.
1141#
1142# There was a crash that could occur when a where clause contains an
1143# alias for an expression in the result set, and that expression retrieves
1144# a column of the second or subsequent table in a join.
1145#
1146do_test where-15.1 {
1147  execsql {
1148    CREATE TEMP TABLE t1 (a, b, c, d, e);
1149    CREATE TEMP TABLE t2 (f);
1150    SELECT t1.e AS alias FROM t2, t1 WHERE alias = 1 ;
1151  }
1152} {}
1153
1154integrity_check {where-99.0}
1155
1156finish_test
1157