1# 2016-05-20 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 LIMIT in combination with ORDER BY 13# and in particular, the optimizations in the inner loop that cause an 14# early exit of the inner loop when the LIMIT is reached and the inner 15# loop is emitting rows in ORDER BY order. 16 17 18set testdir [file dirname $argv0] 19source $testdir/tester.tcl 20set testprefix limit2 21 22do_execsql_test limit2-100 { 23 CREATE TABLE t1(a,b); 24 WITH RECURSIVE c(x) AS (VALUES(1) UNION ALL SELECT x+1 FROM c WHERE x<1000) 25 INSERT INTO t1(a,b) SELECT 1, (x*17)%1000 + 1000 FROM c; 26 INSERT INTO t1(a,b) VALUES(2,2),(3,1006),(4,4),(5,9999); 27 CREATE INDEX t1ab ON t1(a,b); 28} 29set sqlite_search_count 0 30do_execsql_test limit2-100.1 { 31 SELECT a, b, '|' FROM t1 WHERE a IN (2,4,5,3,1) ORDER BY b LIMIT 5; 32} {2 2 | 4 4 | 1 1000 | 1 1001 | 1 1002 |} 33set fast_count $sqlite_search_count 34set sqlite_search_count 0 35do_execsql_test limit2-100.2 { 36 SELECT a, b, '|' FROM t1 WHERE a IN (2,4,5,3,1) ORDER BY +b LIMIT 5; 37} {2 2 | 4 4 | 1 1000 | 1 1001 | 1 1002 |} 38do_test limit2-100.3 { 39 set slow_count $sqlite_search_count 40 expr {$fast_count < 0.02*$slow_count} 41} {1} 42 43do_execsql_test limit2-110 { 44 CREATE TABLE t2(x,y); 45 INSERT INTO t2(x,y) VALUES('a',1),('a',2),('a',3),('a',4); 46 INSERT INTO t2(x,y) VALUES('b',1),('c',2),('d',3),('e',4); 47 CREATE INDEX t2xy ON t2(x,y); 48} 49set sqlite_search_count 0 50do_execsql_test limit2-110.1 { 51 SELECT a, b, '|' FROM t2, t1 WHERE t2.x='a' AND t1.a=t2.y ORDER BY t1.b LIMIT 5; 52} {2 2 | 4 4 | 1 1000 | 1 1001 | 1 1002 |} 53set fast_count $sqlite_search_count 54set sqlite_search_count 0 55do_execsql_test limit2-110.2 { 56 SELECT a, b, '|' FROM t2, t1 WHERE t2.x='a' AND t1.a=t2.y ORDER BY +t1.b LIMIT 5; 57} {2 2 | 4 4 | 1 1000 | 1 1001 | 1 1002 |} 58set slow_count $sqlite_search_count 59do_test limit2-110.3 { 60 expr {$fast_count < 0.02*$slow_count} 61} {1} 62 63do_execsql_test limit2-120 { 64 DROP INDEX t1ab; 65 CREATE INDEX t1ab ON t1(a,b DESC); 66} 67set sqlite_search_count 0 68do_execsql_test limit2-120.1 { 69 SELECT a, b, '|' FROM t1 WHERE a IN (2,4,5,3,1) ORDER BY b DESC LIMIT 5; 70} {5 9999 | 1 1999 | 1 1998 | 1 1997 | 1 1996 |} 71set fast_count $sqlite_search_count 72set sqlite_search_count 0 73do_execsql_test limit2-120.2 { 74 SELECT a, b, '|' FROM t1 WHERE a IN (2,4,5,3,1) ORDER BY +b DESC LIMIT 5; 75} {5 9999 | 1 1999 | 1 1998 | 1 1997 | 1 1996 |} 76do_test limit2-120.3 { 77 set slow_count $sqlite_search_count 78 expr {$fast_count < 0.02*$slow_count} 79} {1} 80 81# Bug report against the new ORDER BY LIMIT optimization just prior to 82# release. (Unreleased so there is no ticket). 83# 84# Make sure the optimization is not applied if the inner loop can only 85# provide a single row of output. 86# 87do_execsql_test limit2-200 { 88 CREATE TABLE t200(a, b); 89 WITH RECURSIVE c(x) AS (VALUES(1) UNION ALL SELECT x+1 FROM c WHERE x<1000) 90 INSERT INTO t200(a,b) SELECT x, x FROM c; 91 CREATE TABLE t201(x INTEGER PRIMARY KEY, y); 92 INSERT INTO t201(x,y) VALUES(2,12345); 93 94 SELECT *, '|' FROM t200, t201 WHERE x=b ORDER BY y LIMIT 3; 95} {2 2 2 12345 |} 96do_execsql_test limit2-210 { 97 SELECT *, '|' FROM t200 LEFT JOIN t201 ON x=b ORDER BY y LIMIT 3; 98} {1 1 {} {} | 3 3 {} {} | 4 4 {} {} |} 99 100# Bug in the ORDER BY LIMIT optimization reported on 2016-09-06. 101# Ticket https://www.sqlite.org/src/info/559733b09e96 102# 103do_execsql_test limit2-300 { 104 CREATE TABLE t300(a,b,c); 105 CREATE INDEX t300x ON t300(a,b,c); 106 INSERT INTO t300 VALUES(0,1,99),(0,1,0),(0,0,0); 107 SELECT *,'.' FROM t300 WHERE a=0 AND (c=0 OR c=99) ORDER BY c DESC; 108} {0 1 99 . 0 0 0 . 0 1 0 .} 109do_execsql_test limit2-310 { 110 SELECT *,'.' FROM t300 WHERE a=0 AND (c=0 OR c=99) ORDER BY c DESC LIMIT 1; 111} {0 1 99 .} 112 113# Make sure the SELECT loop is ordered correctly for the direction of 114# the ORDER BY 115# 116do_execsql_test limit2-400 { 117 CREATE TABLE t400(a,b); 118 CREATE INDEX t400_ab ON t400(a,b); 119 INSERT INTO t400(a,b) VALUES(1,90),(1,40),(2,80),(2,30),(3,70),(3,20); 120 SELECT *,'x' FROM t400 WHERE a IN (1,2,3) ORDER BY b DESC LIMIT 3; 121 SELECT *,'y' FROM t400 WHERE a IN (1,2,3) ORDER BY +b DESC LIMIT 3; 122} {1 90 x 2 80 x 3 70 x 1 90 y 2 80 y 3 70 y} 123 124 125do_execsql_test 500 { 126 CREATE TABLE t500(i INTEGER PRIMARY KEY, j); 127 INSERT INTO t500 VALUES(1, 1); 128 INSERT INTO t500 VALUES(2, 2); 129 INSERT INTO t500 VALUES(3, 3); 130 INSERT INTO t500 VALUES(4, 0); 131 INSERT INTO t500 VALUES(5, 5); 132 SELECT j FROM t500 WHERE i IN (1,2,3,4,5) ORDER BY j DESC LIMIT 3; 133} {5 3 2} 134do_execsql_test 501 { 135 CREATE TABLE t501(i INTEGER PRIMARY KEY, j); 136 INSERT INTO t501 VALUES(1, 5); 137 INSERT INTO t501 VALUES(2, 4); 138 INSERT INTO t501 VALUES(3, 3); 139 INSERT INTO t501 VALUES(4, 6); 140 INSERT INTO t501 VALUES(5, 1); 141 SELECT j FROM t501 WHERE i IN (1,2,3,4,5) ORDER BY j LIMIT 3; 142} {1 3 4} 143do_execsql_test 502 { 144 CREATE TABLE t502(i INT PRIMARY KEY, j); 145 INSERT INTO t502 VALUES(1, 5); 146 INSERT INTO t502 VALUES(2, 4); 147 INSERT INTO t502 VALUES(3, 3); 148 INSERT INTO t502 VALUES(4, 6); 149 INSERT INTO t502 VALUES(5, 1); 150 SELECT j FROM t502 WHERE i IN (1,2,3,4,5) ORDER BY j LIMIT 3; 151} {1 3 4} 152 153# Ticket https://www.sqlite.org/src/info/123c9ba32130a6c9 2017-12-13 154# Incorrect result when an idnex is used for an ordered join. 155# 156# This test case is in the limit2.test module because the problem was first 157# exposed by check-in https://www.sqlite.org/src/info/559733b09e which 158# implemented the ORDER BY LIMIT optimization that limit2.test strives to 159# test. 160# 161do_execsql_test 600 { 162 DROP TABLE IF EXISTS t1; 163 CREATE TABLE t1(a, b); INSERT INTO t1 VALUES(1,2); 164 DROP TABLE IF EXISTS t2; 165 CREATE TABLE t2(x, y); INSERT INTO t2 VALUES(1,3); 166 CREATE INDEX t1ab ON t1(a,b); 167 SELECT y FROM t1, t2 WHERE a=x AND b<=y ORDER BY b DESC; 168} {3} 169 170# Ticket https://www.sqlite.org/src/info/9936b2fa443fec03 2018-09-08 171# Infinite loop due to the ORDER BY LIMIT optimization. 172# 173do_execsql_test 700 { 174 DROP TABLE IF EXISTS t1; 175 DROP TABLE IF EXISTS t2; 176 CREATE TABLE t1(aa VARCHAR PRIMARY KEY NOT NULL,bb,cc,x VARCHAR(400)); 177 INSERT INTO t1(aa,bb,cc) VALUES('maroon','meal','lecture'); 178 INSERT INTO t1(aa,bb,cc) VALUES('reality','meal','catsear'); 179 CREATE TABLE t2(aa VARCHAR PRIMARY KEY, dd INT DEFAULT 1, ee, x VARCHAR(100)); 180 INSERT INTO t2(aa,dd,ee) VALUES('maroon',0,'travel'),('reality',0,'hour'); 181 CREATE INDEX t2x1 ON t2(dd,ee); 182 ANALYZE; 183 DROP TABLE IF EXISTS sqlite_stat4; 184 DELETE FROM sqlite_stat1; 185 INSERT INTO sqlite_stat1 VALUES 186 ('t2','t2x1','3 3 3'), 187 ('t2','sqlite_autoindex_t2_1','3 1'), 188 ('t1','sqlite_autoindex_t1_1','2 1'); 189 ANALYZE sqlite_master; 190 SELECT * 191 FROM t1 LEFT JOIN t2 ON t1.aa=t2.aa 192 WHERE t1.bb='meal' 193 ORDER BY t2.dd DESC 194 LIMIT 1; 195} {maroon meal lecture {} maroon 0 travel {}} 196do_execsql_test 710 { 197 DROP TABLE t1; 198 DROP TABLE t2; 199 CREATE TABLE t1(aa, bb); 200 INSERT INTO t1 VALUES('maroon','meal'); 201 CREATE TABLE t2(cc, dd, ee, x VARCHAR(100)); 202 INSERT INTO t2(cc,dd,ee) VALUES('maroon',1,'one'); 203 INSERT INTO t2(cc,dd,ee) VALUES('maroon',2,'two'); 204 INSERT INTO t2(cc,dd,ee) VALUES('maroon',0,'zero'); 205 CREATE INDEX t2ddee ON t2(dd,ee); 206 CREATE INDEX t2cc ON t2(cc); 207 ANALYZE; 208 SELECT t2.cc, t2.dd, t2.ee FROM t1 CROSS JOIN t2 ON t1.aa=t2.cc 209 ORDER BY t2.dd LIMIT 1; 210} {maroon 0 zero} 211do_execsql_test 720 { 212 SELECT t2.cc, t2.dd, t2.ee FROM t1 CROSS JOIN t2 ON t1.aa=t2.cc 213 WHERE t1.bb='meal' 214 ORDER BY t2.dd LIMIT 1; 215} {maroon 0 zero} 216 217finish_test 218