3 # The author disclaims copyright to this source code. In place of
4 # a legal notice, here is a blessing:
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.
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.
14 # $Id: where.test,v 1.50 2008/11/03 09:06:06 danielk1977 Exp $
16 set testdir [file dirname $argv0]
17 source $testdir/tester.tcl
19 # Build some test data
23 CREATE TABLE t1(w int, x int, y int);
24 CREATE TABLE t2(p int, q int, r int, s int);
26 for {set i 1} {$i<=100} {incr 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)"
35 INSERT INTO t2 SELECT 101-w, x, (SELECT max(y) FROM t1)+1-y, y FROM t1;
38 set maxy [execsql {select max(y) from t1}]
40 INSERT INTO t2 SELECT 101-w, x, $maxy+1-y, y FROM t1;
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);
53 # Do an SQL statement. Append the search count to the end of the result.
56 set ::sqlite_search_count 0
57 return [concat [execsql $sql] $::sqlite_search_count]
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.
66 count {SELECT x, y, w FROM t1 WHERE w=10}
75 db eval {SELECT x, y, w FROM t1 WHERE +w=10}
84 count {SELECT x, y, w AS abc FROM t1 WHERE abc=10}
93 count {SELECT x, y, w FROM t1 WHERE w=11}
96 count {SELECT x, y, w AS abc FROM t1 WHERE abc=11}
99 count {SELECT x, y, w AS abc FROM t1 WHERE 11=w}
101 do_test where-1.3.2 {
102 count {SELECT x, y, w AS abc FROM t1 WHERE 11=abc}
104 do_test where-1.4.1 {
105 count {SELECT w, x, y FROM t1 WHERE 11=w AND x>2}
107 do_test where-1.4.2 {
108 set sqlite_query_plan
110 do_test where-1.4.3 {
111 count {SELECT w AS a, x AS b, y FROM t1 WHERE 11=a AND b>2}
113 do_test where-1.4.4 {
114 set sqlite_query_plan
117 count {SELECT x, y FROM t1 WHERE y<200 AND w=11 AND x>2}
119 do_test where-1.5.2 {
120 set sqlite_query_plan
123 count {SELECT x, y FROM t1 WHERE y<200 AND x>2 AND w=11}
126 count {SELECT x, y FROM t1 WHERE w=11 AND y<200 AND x>2}
129 count {SELECT x, y FROM t1 WHERE w>10 AND y=144 AND x=3}
131 do_test where-1.8.2 {
132 set sqlite_query_plan
134 do_test where-1.8.3 {
135 count {SELECT x, y FROM t1 WHERE y=144 AND x=3}
136 set sqlite_query_plan
139 count {SELECT x, y FROM t1 WHERE y=144 AND w>10 AND x=3}
142 count {SELECT x, y FROM t1 WHERE x=3 AND w>=10 AND y=121}
145 count {SELECT x, y FROM t1 WHERE x=3 AND y=100 AND w<10}
148 # New for SQLite version 2.1: Verify that that inequality constraints
149 # are used correctly.
152 count {SELECT w FROM t1 WHERE x=3 AND y<100}
155 count {SELECT w FROM t1 WHERE x=3 AND 100>y}
158 count {SELECT w FROM t1 WHERE 3=x AND y<100}
161 count {SELECT w FROM t1 WHERE 3=x AND 100>y}
164 count {SELECT w FROM t1 WHERE x=3 AND y<=100}
167 count {SELECT w FROM t1 WHERE x=3 AND 100>=y}
170 count {SELECT w FROM t1 WHERE x=3 AND y>225}
173 count {SELECT w FROM t1 WHERE x=3 AND 225<y}
176 count {SELECT w FROM t1 WHERE x=3 AND y>=225}
179 count {SELECT w FROM t1 WHERE x=3 AND 225<=y}
182 count {SELECT w FROM t1 WHERE x=3 AND y>121 AND y<196}
185 count {SELECT w FROM t1 WHERE x=3 AND y>=121 AND y<=196}
188 count {SELECT w FROM t1 WHERE x=3 AND 121<y AND 196>y}
191 count {SELECT w FROM t1 WHERE x=3 AND 121<=y AND 196>=y}
194 # Need to work on optimizing the BETWEEN operator.
196 # do_test where-1.26 {
197 # count {SELECT w FROM t1 WHERE x=3 AND y BETWEEN 121 AND 196}
201 count {SELECT w FROM t1 WHERE x=3 AND y+1==122}
205 count {SELECT w FROM t1 WHERE x+1=4 AND y+1==122}
208 count {SELECT w FROM t1 WHERE y==121}
213 count {SELECT w FROM t1 WHERE w>97}
216 count {SELECT w FROM t1 WHERE w>=97}
219 count {SELECT w FROM t1 WHERE w==97}
221 do_test where-1.33.1 {
222 count {SELECT w FROM t1 WHERE w<=97 AND w==97}
224 do_test where-1.33.2 {
225 count {SELECT w FROM t1 WHERE w<98 AND w==97}
227 do_test where-1.33.3 {
228 count {SELECT w FROM t1 WHERE w>=97 AND w==97}
230 do_test where-1.33.4 {
231 count {SELECT w FROM t1 WHERE w>96 AND w==97}
233 do_test where-1.33.5 {
234 count {SELECT w FROM t1 WHERE w==97 AND w==97}
237 count {SELECT w FROM t1 WHERE w+1==98}
240 count {SELECT w FROM t1 WHERE w<3}
243 count {SELECT w FROM t1 WHERE w<=3}
246 count {SELECT w FROM t1 WHERE w+1<=4 ORDER BY w}
250 count {SELECT (w) FROM t1 WHERE (w)>(97)}
253 count {SELECT (w) FROM t1 WHERE (w)>=(97)}
256 count {SELECT (w) FROM t1 WHERE (w)==(97)}
259 count {SELECT (w) FROM t1 WHERE ((w)+(1))==(98)}
263 # Do the same kind of thing except use a join as the data source.
267 SELECT w, p FROM t2, t1
268 WHERE x=q AND y=s AND r=8977
273 SELECT w, p FROM t2, t1
274 WHERE x=q AND s=y AND r=8977
279 SELECT w, p FROM t2, t1
280 WHERE x=q AND s=y AND r=8977 AND w>10
285 SELECT w, p FROM t2, t1
286 WHERE p<80 AND x=q AND s=y AND r=8977 AND w>10
291 SELECT w, p FROM t2, t1
292 WHERE p<80 AND x=q AND 8977=r AND s=y AND w>10
297 SELECT w, p FROM t2, t1
298 WHERE x=q AND p=77 AND s=y AND w>5
303 SELECT w, p FROM t1, t2
304 WHERE x=q AND p>77 AND s=y AND w=5
308 # Lets do a 3-way join.
312 SELECT A.w, B.p, C.w FROM t1 as A, t2 as B, t1 as C
313 WHERE C.w=101-B.p AND B.r=10202-A.y AND A.w=11
318 SELECT A.w, B.p, C.w FROM t1 as A, t2 as B, t1 as C
319 WHERE C.w=101-B.p AND B.r=10202-A.y AND A.w=12
324 SELECT A.w, B.p, C.w FROM t1 as A, t2 as B, t1 as C
325 WHERE A.w=15 AND B.p=C.w AND B.r=10202-A.y
329 # Test to see that the special case of a constant WHERE clause is
334 SELECT * FROM t1 WHERE 0
339 SELECT * FROM t1 WHERE 1 LIMIT 1
364 SELECT count(*) FROM t1 WHERE t1.w
368 # Verify that IN operators in a WHERE clause are handled correctly.
369 # Omit these tests if the build is not capable of sub-queries.
374 SELECT * FROM t1 WHERE rowid IN (1,2,3,1234) order by 1;
376 } {1 0 4 2 1 9 3 1 16 4}
379 SELECT * FROM t1 WHERE rowid+0 IN (1,2,3,1234) order by 1;
381 } {1 0 4 2 1 9 3 1 16 102}
384 SELECT * FROM t1 WHERE w IN (-1,1,2,3) order by 1;
386 } {1 0 4 2 1 9 3 1 16 14}
389 SELECT * FROM t1 WHERE w+0 IN (-1,1,2,3) order by 1;
391 } {1 0 4 2 1 9 3 1 16 102}
394 SELECT * FROM t1 WHERE rowid IN
395 (select rowid from t1 where rowid IN (-1,2,4))
401 SELECT * FROM t1 WHERE rowid+0 IN
402 (select rowid from t1 where rowid IN (-1,2,4))
408 SELECT * FROM t1 WHERE w IN
409 (select rowid from t1 where rowid IN (-1,2,4))
415 SELECT * FROM t1 WHERE w+0 IN
416 (select rowid from t1 where rowid IN (-1,2,4))
422 SELECT * FROM t1 WHERE x IN (1,7) ORDER BY 1;
427 SELECT * FROM t1 WHERE x+0 IN (1,7) ORDER BY 1;
432 SELECT * FROM t1 WHERE y IN (6400,8100) ORDER BY 1;
434 } {79 6 6400 89 6 8100 199}
437 SELECT * FROM t1 WHERE x=6 AND y IN (6400,8100) ORDER BY 1;
439 } {79 6 6400 89 6 8100 7}
442 SELECT * FROM t1 WHERE x IN (1,7) AND y NOT IN (6400,8100) ORDER BY 1;
447 SELECT * FROM t1 WHERE x IN (1,7) AND y IN (9,10) ORDER BY 1;
452 SELECT * FROM t1 WHERE x IN (1,7) AND y IN (9,16) ORDER BY 1;
457 # This procedure executes the SQL. Then it checks to see if the OP_Sort
458 # opcode was executed. If an OP_Sort did occur, then "sort" is appended
459 # to the result. If no OP_Sort happened, then "nosort" is appended.
461 # This procedure is used to check to make sure sorting is or is not
462 # occurring as expected.
465 set data [execsql $sql]
466 if {[db status sort]} {set x sort} {set x nosort}
470 # Check out the logic that attempts to implement the ORDER BY clause
471 # using an index rather than by sorting.
475 CREATE TABLE t3(a,b,c);
476 CREATE INDEX t3a ON t3(a);
477 CREATE INDEX t3bc ON t3(b,c);
478 CREATE INDEX t3acb ON t3(a,c,b);
479 INSERT INTO t3 SELECT w, 101-w, y FROM t1;
480 SELECT count(*), sum(a), sum(b), sum(c) FROM t3;
482 } {100 5050 5050 348550}
485 SELECT * FROM t3 ORDER BY a LIMIT 3
487 } {1 100 4 2 99 9 3 98 16 nosort}
490 SELECT * FROM t3 ORDER BY a+1 LIMIT 3
492 } {1 100 4 2 99 9 3 98 16 sort}
495 SELECT * FROM t3 WHERE a<10 ORDER BY a LIMIT 3
497 } {1 100 4 2 99 9 3 98 16 nosort}
500 SELECT * FROM t3 WHERE a>0 AND a<10 ORDER BY a LIMIT 3
502 } {1 100 4 2 99 9 3 98 16 nosort}
505 SELECT * FROM t3 WHERE a>0 ORDER BY a LIMIT 3
507 } {1 100 4 2 99 9 3 98 16 nosort}
510 SELECT * FROM t3 WHERE b>0 ORDER BY a LIMIT 3
512 } {1 100 4 2 99 9 3 98 16 nosort}
516 SELECT * FROM t3 WHERE a IN (3,5,7,1,9,4,2) ORDER BY a LIMIT 3
518 } {1 100 4 2 99 9 3 98 16 sort}
520 do_test where-6.9.1 {
522 SELECT * FROM t3 WHERE a=1 AND c>0 ORDER BY a LIMIT 3
525 do_test where-6.9.1.1 {
527 SELECT * FROM t3 WHERE a>=1 AND a=1 AND c>0 ORDER BY a LIMIT 3
530 do_test where-6.9.1.2 {
532 SELECT * FROM t3 WHERE a<2 AND a=1 AND c>0 ORDER BY a LIMIT 3
535 do_test where-6.9.2 {
537 SELECT * FROM t3 WHERE a=1 AND c>0 ORDER BY a,c LIMIT 3
540 do_test where-6.9.3 {
542 SELECT * FROM t3 WHERE a=1 AND c>0 ORDER BY c LIMIT 3
545 do_test where-6.9.4 {
547 SELECT * FROM t3 WHERE a=1 AND c>0 ORDER BY a DESC LIMIT 3
550 do_test where-6.9.5 {
552 SELECT * FROM t3 WHERE a=1 AND c>0 ORDER BY a DESC, c DESC LIMIT 3
555 do_test where-6.9.6 {
557 SELECT * FROM t3 WHERE a=1 AND c>0 ORDER BY c DESC LIMIT 3
560 do_test where-6.9.7 {
562 SELECT * FROM t3 WHERE a=1 AND c>0 ORDER BY c,a LIMIT 3
565 do_test where-6.9.8 {
567 SELECT * FROM t3 WHERE a=1 AND c>0 ORDER BY a DESC, c ASC LIMIT 3
570 do_test where-6.9.9 {
572 SELECT * FROM t3 WHERE a=1 AND c>0 ORDER BY a ASC, c DESC LIMIT 3
577 SELECT * FROM t3 WHERE a=1 AND c>0 ORDER BY a LIMIT 3
582 SELECT * FROM t3 WHERE a=1 AND c>0 ORDER BY a,c LIMIT 3
587 SELECT * FROM t3 WHERE a=1 AND c>0 ORDER BY a,c,b LIMIT 3
592 SELECT * FROM t3 WHERE a>0 ORDER BY a DESC LIMIT 3
594 } {100 1 10201 99 2 10000 98 3 9801 nosort}
595 do_test where-6.13.1 {
597 SELECT * FROM t3 WHERE a>0 ORDER BY -a LIMIT 3
599 } {100 1 10201 99 2 10000 98 3 9801 sort}
602 SELECT * FROM t3 ORDER BY b LIMIT 3
604 } {100 1 10201 99 2 10000 98 3 9801 nosort}
607 SELECT t3.a, t1.x FROM t3, t1 WHERE t3.a=t1.w ORDER BY t3.a LIMIT 3
609 } {1 0 2 1 3 1 nosort}
612 SELECT t3.a, t1.x FROM t3, t1 WHERE t3.a=t1.w ORDER BY t1.x, t3.a LIMIT 3
617 SELECT y FROM t1 ORDER BY w LIMIT 3;
622 SELECT y FROM t1 ORDER BY rowid LIMIT 3;
627 SELECT y FROM t1 ORDER BY rowid, y LIMIT 3;
632 SELECT y FROM t1 ORDER BY rowid, y DESC LIMIT 3;
637 SELECT y FROM t1 WHERE y>4 ORDER BY rowid, w, x LIMIT 3;
642 SELECT y FROM t1 WHERE y>=9 ORDER BY rowid, x DESC, w LIMIT 3;
647 SELECT y FROM t1 WHERE y>4 AND y<25 ORDER BY rowid;
652 SELECT y FROM t1 WHERE y>=4 AND y<=25 ORDER BY oid;
657 SELECT y FROM t1 WHERE y<=25 ORDER BY _rowid_, w+y;
662 # Tests for reverse-order sorting.
666 SELECT w FROM t1 WHERE x=3 ORDER BY y;
668 } {8 9 10 11 12 13 14 15 nosort}
671 SELECT w FROM t1 WHERE x=3 ORDER BY y DESC;
673 } {15 14 13 12 11 10 9 8 nosort}
676 SELECT w FROM t1 WHERE x=3 AND y>100 ORDER BY y LIMIT 3;
681 SELECT w FROM t1 WHERE x=3 AND y>100 ORDER BY y DESC LIMIT 3;
686 SELECT w FROM t1 WHERE x=3 AND y>121 ORDER BY y DESC;
688 } {15 14 13 12 11 nosort}
691 SELECT w FROM t1 WHERE x=3 AND y>=121 ORDER BY y DESC;
693 } {15 14 13 12 11 10 nosort}
696 SELECT w FROM t1 WHERE x=3 AND y>=121 AND y<196 ORDER BY y DESC;
701 SELECT w FROM t1 WHERE x=3 AND y>=121 AND y<=196 ORDER BY y DESC;
703 } {13 12 11 10 nosort}
706 SELECT w FROM t1 WHERE x=3 AND y>121 AND y<=196 ORDER BY y DESC;
711 SELECT w FROM t1 WHERE x=3 AND y>100 AND y<196 ORDER BY y DESC;
716 SELECT w FROM t1 WHERE x=3 AND y>=121 AND y<196 ORDER BY y;
721 SELECT w FROM t1 WHERE x=3 AND y>=121 AND y<=196 ORDER BY y;
723 } {10 11 12 13 nosort}
726 SELECT w FROM t1 WHERE x=3 AND y>121 AND y<=196 ORDER BY y;
731 SELECT w FROM t1 WHERE x=3 AND y>100 AND y<196 ORDER BY y;
736 SELECT w FROM t1 WHERE x=3 AND y<81 ORDER BY y;
741 SELECT w FROM t1 WHERE x=3 AND y<=81 ORDER BY y;
746 SELECT w FROM t1 WHERE x=3 AND y>256 ORDER BY y;
751 SELECT w FROM t1 WHERE x=3 AND y>=256 ORDER BY y;
756 SELECT w FROM t1 WHERE x=3 AND y<81 ORDER BY y DESC;
761 SELECT w FROM t1 WHERE x=3 AND y<=81 ORDER BY y DESC;
766 SELECT w FROM t1 WHERE x=3 AND y>256 ORDER BY y DESC;
771 SELECT w FROM t1 WHERE x=3 AND y>=256 ORDER BY y DESC;
776 SELECT w FROM t1 WHERE x=0 AND y<4 ORDER BY y;
781 SELECT w FROM t1 WHERE x=0 AND y<=4 ORDER BY y;
786 SELECT w FROM t1 WHERE x=6 AND y>10201 ORDER BY y;
791 SELECT w FROM t1 WHERE x=6 AND y>=10201 ORDER BY y;
796 SELECT w FROM t1 WHERE x=0 AND y<4 ORDER BY y DESC;
801 SELECT w FROM t1 WHERE x=0 AND y<=4 ORDER BY y DESC;
806 SELECT w FROM t1 WHERE x=6 AND y>10201 ORDER BY y DESC;
811 SELECT w FROM t1 WHERE x=6 AND y>=10201 ORDER BY y DESC;
816 SELECT y FROM t1 ORDER BY rowid DESC LIMIT 3
818 } {10201 10000 9801 nosort}
821 SELECT y FROM t1 WHERE y<25 ORDER BY rowid DESC
826 SELECT y FROM t1 WHERE y<=25 ORDER BY rowid DESC
831 SELECT y FROM t1 WHERE y<25 AND y>4 ORDER BY rowid DESC, y DESC
836 SELECT y FROM t1 WHERE y<25 AND y>=4 ORDER BY rowid DESC
842 CREATE TABLE t4 AS SELECT * FROM t1;
843 CREATE INDEX i4xy ON t4(x,y);
846 SELECT w FROM t4 WHERE x=4 and y<1000 ORDER BY y DESC limit 3;
854 SELECT w FROM t4 WHERE x=4 and y<1000 ORDER BY y DESC limit 3;
858 # Make sure searches with an index work with an empty table.
862 CREATE TABLE t5(x PRIMARY KEY);
863 SELECT * FROM t5 WHERE x<10;
868 SELECT * FROM t5 WHERE x<10 ORDER BY x DESC;
873 SELECT * FROM t5 WHERE x=10;
879 SELECT 1 WHERE abs(random())<0
883 proc tclvar_func {vname} {return [set ::$vname]}
884 db function tclvar tclvar_func
887 SELECT count(*) FROM t1 WHERE tclvar('v1');
893 SELECT count(*) FROM t1 WHERE tclvar('v1');
898 proc tclvar_func {vname} {
904 SELECT count(*) FROM t1 WHERE tclvar('v1');
908 # Ticket #1376. The query below was causing a segfault.
909 # The problem was the age-old error of calling realloc() on an
910 # array while there are still pointers to individual elements of
915 CREATE TABLE t99(Dte INT, X INT);
916 DELETE FROM t99 WHERE (Dte = 2451337) OR (Dte = 2451339) OR
917 (Dte BETWEEN 2451345 AND 2451347) OR (Dte = 2451351) OR
918 (Dte BETWEEN 2451355 AND 2451356) OR (Dte = 2451358) OR
919 (Dte = 2451362) OR (Dte = 2451365) OR (Dte = 2451367) OR
920 (Dte BETWEEN 2451372 AND 2451376) OR (Dte BETWEEN 2451382 AND 2451384) OR
921 (Dte = 2451387) OR (Dte BETWEEN 2451389 AND 2451391) OR
922 (Dte BETWEEN 2451393 AND 2451395) OR (Dte = 2451400) OR
923 (Dte = 2451402) OR (Dte = 2451404) OR (Dte BETWEEN 2451416 AND 2451418) OR
924 (Dte = 2451422) OR (Dte = 2451426) OR (Dte BETWEEN 2451445 AND 2451446) OR
925 (Dte = 2451456) OR (Dte = 2451458) OR (Dte BETWEEN 2451465 AND 2451467) OR
926 (Dte BETWEEN 2451469 AND 2451471) OR (Dte = 2451474) OR
927 (Dte BETWEEN 2451477 AND 2451501) OR (Dte BETWEEN 2451503 AND 2451509) OR
928 (Dte BETWEEN 2451511 AND 2451514) OR (Dte BETWEEN 2451518 AND 2451521) OR
929 (Dte BETWEEN 2451523 AND 2451531) OR (Dte BETWEEN 2451533 AND 2451537) OR
930 (Dte BETWEEN 2451539 AND 2451544) OR (Dte BETWEEN 2451546 AND 2451551) OR
931 (Dte BETWEEN 2451553 AND 2451555) OR (Dte = 2451557) OR
932 (Dte BETWEEN 2451559 AND 2451561) OR (Dte = 2451563) OR
933 (Dte BETWEEN 2451565 AND 2451566) OR (Dte BETWEEN 2451569 AND 2451571) OR
934 (Dte = 2451573) OR (Dte = 2451575) OR (Dte = 2451577) OR (Dte = 2451581) OR
935 (Dte BETWEEN 2451583 AND 2451586) OR (Dte BETWEEN 2451588 AND 2451592) OR
936 (Dte BETWEEN 2451596 AND 2451598) OR (Dte = 2451600) OR
937 (Dte BETWEEN 2451602 AND 2451603) OR (Dte = 2451606) OR (Dte = 2451611);
941 # Ticket #2116: Make sure sorting by index works well with nn INTEGER PRIMARY
946 CREATE TABLE t6(a INTEGER PRIMARY KEY, b TEXT);
947 INSERT INTO t6 VALUES(1,'one');
948 INSERT INTO t6 VALUES(4,'four');
949 CREATE INDEX t6i1 ON t6(b);
952 SELECT * FROM t6 ORDER BY b;
954 } {4 four 1 one nosort}
957 SELECT * FROM t6 ORDER BY b, a;
959 } {4 four 1 one nosort}
962 SELECT * FROM t6 ORDER BY a;
964 } {1 one 4 four nosort}
967 SELECT * FROM t6 ORDER BY a, b;
969 } {1 one 4 four nosort}
972 SELECT * FROM t6 ORDER BY b DESC;
974 } {1 one 4 four nosort}
977 SELECT * FROM t6 ORDER BY b DESC, a DESC;
979 } {1 one 4 four nosort}
982 SELECT * FROM t6 ORDER BY b DESC, a ASC;
984 } {1 one 4 four sort}
987 SELECT * FROM t6 ORDER BY b ASC, a DESC;
989 } {4 four 1 one sort}
992 SELECT * FROM t6 ORDER BY a DESC;
994 } {4 four 1 one nosort}
995 do_test where-12.10 {
997 SELECT * FROM t6 ORDER BY a DESC, b DESC;
999 } {4 four 1 one nosort}
1000 do_test where-12.11 {
1002 SELECT * FROM t6 ORDER BY a DESC, b ASC;
1004 } {4 four 1 one nosort}
1005 do_test where-12.12 {
1007 SELECT * FROM t6 ORDER BY a ASC, b DESC;
1009 } {1 one 4 four nosort}
1010 do_test where-13.1 {
1012 CREATE TABLE t7(a INTEGER PRIMARY KEY, b TEXT);
1013 INSERT INTO t7 VALUES(1,'one');
1014 INSERT INTO t7 VALUES(4,'four');
1015 CREATE INDEX t7i1 ON t7(b);
1018 SELECT * FROM t7 ORDER BY b;
1020 } {4 four 1 one nosort}
1021 do_test where-13.2 {
1023 SELECT * FROM t7 ORDER BY b, a;
1025 } {4 four 1 one nosort}
1026 do_test where-13.3 {
1028 SELECT * FROM t7 ORDER BY a;
1030 } {1 one 4 four nosort}
1031 do_test where-13.4 {
1033 SELECT * FROM t7 ORDER BY a, b;
1035 } {1 one 4 four nosort}
1036 do_test where-13.5 {
1038 SELECT * FROM t7 ORDER BY b DESC;
1040 } {1 one 4 four nosort}
1041 do_test where-13.6 {
1043 SELECT * FROM t7 ORDER BY b DESC, a DESC;
1045 } {1 one 4 four nosort}
1046 do_test where-13.7 {
1048 SELECT * FROM t7 ORDER BY b DESC, a ASC;
1050 } {1 one 4 four sort}
1051 do_test where-13.8 {
1053 SELECT * FROM t7 ORDER BY b ASC, a DESC;
1055 } {4 four 1 one sort}
1056 do_test where-13.9 {
1058 SELECT * FROM t7 ORDER BY a DESC;
1060 } {4 four 1 one nosort}
1061 do_test where-13.10 {
1063 SELECT * FROM t7 ORDER BY a DESC, b DESC;
1065 } {4 four 1 one nosort}
1066 do_test where-13.11 {
1068 SELECT * FROM t7 ORDER BY a DESC, b ASC;
1070 } {4 four 1 one nosort}
1071 do_test where-13.12 {
1073 SELECT * FROM t7 ORDER BY a ASC, b DESC;
1075 } {1 one 4 four nosort}
1079 # When optimizing out ORDER BY clauses, make sure that trailing terms
1080 # of the ORDER BY clause do not reference other tables in a join.
1082 do_test where-14.1 {
1084 CREATE TABLE t8(a INTEGER PRIMARY KEY, b TEXT UNIQUE);
1085 INSERT INTO t8 VALUES(1,'one');
1086 INSERT INTO t8 VALUES(4,'four');
1089 SELECT x.a || '/' || y.a FROM t8 x, t8 y ORDER BY x.a, y.b
1091 } {1/4 1/1 4/4 4/1 sort}
1092 do_test where-14.2 {
1094 SELECT x.a || '/' || y.a FROM t8 x, t8 y ORDER BY x.a, y.b DESC
1096 } {1/1 1/4 4/1 4/4 sort}
1097 do_test where-14.3 {
1099 SELECT x.a || '/' || y.a FROM t8 x, t8 y ORDER BY x.a, x.b
1101 } {1/1 1/4 4/1 4/4 nosort}
1102 do_test where-14.4 {
1104 SELECT x.a || '/' || y.a FROM t8 x, t8 y ORDER BY x.a, x.b DESC
1106 } {1/1 1/4 4/1 4/4 nosort}
1107 do_test where-14.5 {
1109 SELECT x.a || '/' || y.a FROM t8 x, t8 y ORDER BY x.b, x.a||x.b
1111 } {4/1 4/4 1/1 1/4 nosort}
1112 do_test where-14.6 {
1114 SELECT x.a || '/' || y.a FROM t8 x, t8 y ORDER BY x.b, x.a||x.b DESC
1116 } {4/1 4/4 1/1 1/4 nosort}
1117 do_test where-14.7 {
1119 SELECT x.a || '/' || y.a FROM t8 x, t8 y ORDER BY x.b, y.a||y.b
1121 } {4/1 4/4 1/1 1/4 sort}
1122 do_test where-14.7.1 {
1124 SELECT x.a || '/' || y.a FROM t8 x, t8 y ORDER BY x.b, x.a, y.a||y.b
1126 } {4/1 4/4 1/1 1/4 sort}
1127 do_test where-14.7.2 {
1129 SELECT x.a || '/' || y.a FROM t8 x, t8 y ORDER BY x.b, x.a, x.a||x.b
1131 } {4/1 4/4 1/1 1/4 nosort}
1132 do_test where-14.8 {
1134 SELECT x.a || '/' || y.a FROM t8 x, t8 y ORDER BY x.b, y.a||y.b DESC
1136 } {4/4 4/1 1/4 1/1 sort}
1137 do_test where-14.9 {
1139 SELECT x.a || '/' || y.a FROM t8 x, t8 y ORDER BY x.b, x.a||y.b
1141 } {4/4 4/1 1/4 1/1 sort}
1142 do_test where-14.10 {
1144 SELECT x.a || '/' || y.a FROM t8 x, t8 y ORDER BY x.b, x.a||y.b DESC
1146 } {4/1 4/4 1/1 1/4 sort}
1147 do_test where-14.11 {
1149 SELECT x.a || '/' || y.a FROM t8 x, t8 y ORDER BY x.b, y.a||x.b
1151 } {4/1 4/4 1/1 1/4 sort}
1152 do_test where-14.12 {
1154 SELECT x.a || '/' || y.a FROM t8 x, t8 y ORDER BY x.b, y.a||x.b DESC
1156 } {4/4 4/1 1/4 1/1 sort}
1160 # There was a crash that could occur when a where clause contains an
1161 # alias for an expression in the result set, and that expression retrieves
1162 # a column of the second or subsequent table in a join.
1164 do_test where-15.1 {
1166 CREATE TEMP TABLE t1 (a, b, c, d, e);
1167 CREATE TEMP TABLE t2 (f);
1168 SELECT t1.e AS alias FROM t2, t1 WHERE alias = 1 ;
1174 # The branch of code in where.c that generated rowid lookups was
1175 # incorrectly deallocating a constant register, meaning that if the
1176 # vdbe code ran more than once, the second time around the constant
1177 # value may have been clobbered by some other value.
1179 do_test where-16.1 {
1181 CREATE TABLE a1(id INTEGER PRIMARY KEY, v);
1182 CREATE TABLE a2(id INTEGER PRIMARY KEY, v);
1183 INSERT INTO a1 VALUES(1, 'one');
1184 INSERT INTO a1 VALUES(2, 'two');
1185 INSERT INTO a2 VALUES(1, 'one');
1186 INSERT INTO a2 VALUES(2, 'two');
1189 do_test where-16.2 {
1191 SELECT * FROM a2 CROSS JOIN a1 WHERE a1.id=1 AND a1.v='one';
1193 } {1 one 1 one 2 two 1 one}
1195 # The actual problem reported in #3408.
1196 do_test where-16.3 {
1198 CREATE TEMP TABLE foo(idx INTEGER);
1199 INSERT INTO foo VALUES(1);
1200 INSERT INTO foo VALUES(1);
1201 INSERT INTO foo VALUES(1);
1202 INSERT INTO foo VALUES(2);
1203 INSERT INTO foo VALUES(2);
1204 CREATE TEMP TABLE bar(stuff INTEGER);
1205 INSERT INTO bar VALUES(100);
1206 INSERT INTO bar VALUES(200);
1207 INSERT INTO bar VALUES(300);
1210 do_test where-16.4 {
1212 SELECT bar.RowID id FROM foo, bar WHERE foo.idx = bar.RowID AND id = 2;
1216 integrity_check {where-99.0}
1218 #---------------------------------------------------------------------
1219 # These tests test that a bug surrounding the use of ForceInt has been
1222 do_test where-17.1 {
1224 CREATE TABLE tbooking (
1225 id INTEGER PRIMARY KEY,
1226 eventtype INTEGER NOT NULL
1228 INSERT INTO tbooking VALUES(42, 3);
1229 INSERT INTO tbooking VALUES(43, 4);
1232 do_test where-17.2 {
1236 WHERE a.eventtype=3;
1239 do_test where-17.3 {
1241 SELECT a.id, (SELECT b.id FROM tbooking AS b WHERE b.id>a.id)
1243 WHERE a.eventtype=3;
1246 do_test where-17.4 {
1248 SELECT a.id, (SELECT b.id FROM tbooking AS b WHERE b.id>a.id)
1249 FROM (SELECT 1.5 AS id) AS a
1252 do_test where-17.5 {
1254 CREATE TABLE tother(a, b);
1255 INSERT INTO tother VALUES(1, 3.7);
1256 SELECT id, a FROM tbooking, tother WHERE id>a;