xref: /sqlite-3.40.0/test/limit2.test (revision 6ee5a7b4)
173fa4737Sdrh# 2016-05-20
273fa4737Sdrh#
373fa4737Sdrh# The author disclaims copyright to this source code.  In place of
473fa4737Sdrh# a legal notice, here is a blessing:
573fa4737Sdrh#
673fa4737Sdrh#    May you do good and not evil.
773fa4737Sdrh#    May you find forgiveness for yourself and forgive others.
873fa4737Sdrh#    May you share freely, never taking more than you give.
973fa4737Sdrh#
1073fa4737Sdrh#***********************************************************************
1173fa4737Sdrh# This file implements regression tests for SQLite library.  The
1273fa4737Sdrh# focus of this file is testing the LIMIT in combination with ORDER BY
1373fa4737Sdrh# and in particular, the optimizations in the inner loop that cause an
1473fa4737Sdrh# early exit of the inner loop when the LIMIT is reached and the inner
1573fa4737Sdrh# loop is emitting rows in ORDER BY order.
1673fa4737Sdrh
1773fa4737Sdrh
1873fa4737Sdrhset testdir [file dirname $argv0]
1973fa4737Sdrhsource $testdir/tester.tcl
2083465a66Sdanset testprefix limit2
2173fa4737Sdrh
2273fa4737Sdrhdo_execsql_test limit2-100 {
2373fa4737Sdrh  CREATE TABLE t1(a,b);
2473fa4737Sdrh  WITH RECURSIVE c(x) AS (VALUES(1) UNION ALL SELECT x+1 FROM c WHERE x<1000)
2573fa4737Sdrh    INSERT INTO t1(a,b) SELECT 1, (x*17)%1000 + 1000 FROM c;
2673fa4737Sdrh  INSERT INTO t1(a,b) VALUES(2,2),(3,1006),(4,4),(5,9999);
2773fa4737Sdrh  CREATE INDEX t1ab ON t1(a,b);
2873fa4737Sdrh}
2973fa4737Sdrhset sqlite_search_count 0
3073fa4737Sdrhdo_execsql_test limit2-100.1 {
3173fa4737Sdrh  SELECT a, b, '|' FROM t1 WHERE a IN (2,4,5,3,1) ORDER BY b LIMIT 5;
3273fa4737Sdrh} {2 2 | 4 4 | 1 1000 | 1 1001 | 1 1002 |}
3373fa4737Sdrhset fast_count $sqlite_search_count
3473fa4737Sdrhset sqlite_search_count 0
3573fa4737Sdrhdo_execsql_test limit2-100.2 {
3673fa4737Sdrh  SELECT a, b, '|' FROM t1 WHERE a IN (2,4,5,3,1) ORDER BY +b LIMIT 5;
3773fa4737Sdrh} {2 2 | 4 4 | 1 1000 | 1 1001 | 1 1002 |}
3873fa4737Sdrhdo_test limit2-100.3 {
3973fa4737Sdrh  set slow_count $sqlite_search_count
4073fa4737Sdrh  expr {$fast_count < 0.02*$slow_count}
4173fa4737Sdrh} {1}
4273fa4737Sdrh
4373fa4737Sdrhdo_execsql_test limit2-110 {
4473fa4737Sdrh  CREATE TABLE t2(x,y);
4573fa4737Sdrh  INSERT INTO t2(x,y) VALUES('a',1),('a',2),('a',3),('a',4);
4673fa4737Sdrh  INSERT INTO t2(x,y) VALUES('b',1),('c',2),('d',3),('e',4);
4773fa4737Sdrh  CREATE INDEX t2xy ON t2(x,y);
4873fa4737Sdrh}
4973fa4737Sdrhset sqlite_search_count 0
5073fa4737Sdrhdo_execsql_test limit2-110.1 {
5173fa4737Sdrh  SELECT a, b, '|' FROM t2, t1 WHERE t2.x='a' AND t1.a=t2.y ORDER BY t1.b LIMIT 5;
5273fa4737Sdrh} {2 2 | 4 4 | 1 1000 | 1 1001 | 1 1002 |}
5373fa4737Sdrhset fast_count $sqlite_search_count
5473fa4737Sdrhset sqlite_search_count 0
5573fa4737Sdrhdo_execsql_test limit2-110.2 {
5673fa4737Sdrh  SELECT a, b, '|' FROM t2, t1 WHERE t2.x='a' AND t1.a=t2.y ORDER BY +t1.b LIMIT 5;
5773fa4737Sdrh} {2 2 | 4 4 | 1 1000 | 1 1001 | 1 1002 |}
5873fa4737Sdrhset slow_count $sqlite_search_count
5973fa4737Sdrhdo_test limit2-110.3 {
6073fa4737Sdrh  expr {$fast_count < 0.02*$slow_count}
6173fa4737Sdrh} {1}
6273fa4737Sdrh
6373fa4737Sdrhdo_execsql_test limit2-120 {
6473fa4737Sdrh  DROP INDEX t1ab;
6573fa4737Sdrh  CREATE INDEX t1ab ON t1(a,b DESC);
6673fa4737Sdrh}
6773fa4737Sdrhset sqlite_search_count 0
6873fa4737Sdrhdo_execsql_test limit2-120.1 {
6973fa4737Sdrh  SELECT a, b, '|' FROM t1 WHERE a IN (2,4,5,3,1) ORDER BY b DESC LIMIT 5;
7073fa4737Sdrh} {5 9999 | 1 1999 | 1 1998 | 1 1997 | 1 1996 |}
7173fa4737Sdrhset fast_count $sqlite_search_count
7273fa4737Sdrhset sqlite_search_count 0
7373fa4737Sdrhdo_execsql_test limit2-120.2 {
7473fa4737Sdrh  SELECT a, b, '|' FROM t1 WHERE a IN (2,4,5,3,1) ORDER BY +b DESC LIMIT 5;
7573fa4737Sdrh} {5 9999 | 1 1999 | 1 1998 | 1 1997 | 1 1996 |}
7673fa4737Sdrhdo_test limit2-120.3 {
7773fa4737Sdrh  set slow_count $sqlite_search_count
7873fa4737Sdrh  expr {$fast_count < 0.02*$slow_count}
7973fa4737Sdrh} {1}
8073fa4737Sdrh
81dd545d3bSdrh# Bug report against the new ORDER BY LIMIT optimization just prior to
82dd545d3bSdrh# release.  (Unreleased so there is no ticket).
83dd545d3bSdrh#
84dd545d3bSdrh# Make sure the optimization is not applied if the inner loop can only
85dd545d3bSdrh# provide a single row of output.
86dd545d3bSdrh#
87dd545d3bSdrhdo_execsql_test limit2-200 {
88dd545d3bSdrh  CREATE TABLE t200(a, b);
89dd545d3bSdrh  WITH RECURSIVE c(x) AS (VALUES(1) UNION ALL SELECT x+1 FROM c WHERE x<1000)
90dd545d3bSdrh    INSERT INTO t200(a,b) SELECT x, x FROM c;
91dd545d3bSdrh  CREATE TABLE t201(x INTEGER PRIMARY KEY, y);
92dd545d3bSdrh  INSERT INTO t201(x,y) VALUES(2,12345);
93dd545d3bSdrh
94dd545d3bSdrh  SELECT *, '|' FROM t200, t201 WHERE x=b ORDER BY y LIMIT 3;
95dd545d3bSdrh} {2 2 2 12345 |}
96dd545d3bSdrhdo_execsql_test limit2-210 {
97dd545d3bSdrh  SELECT *, '|' FROM t200 LEFT JOIN t201 ON x=b ORDER BY y LIMIT 3;
98dd545d3bSdrh} {1 1 {} {} | 3 3 {} {} | 4 4 {} {} |}
99dd545d3bSdrh
10057a8c615Sdrh# Bug in the ORDER BY LIMIT optimization reported on 2016-09-06.
10157a8c615Sdrh# Ticket https://www.sqlite.org/src/info/559733b09e96
10257a8c615Sdrh#
10357a8c615Sdrhdo_execsql_test limit2-300 {
10457a8c615Sdrh  CREATE TABLE t300(a,b,c);
10557a8c615Sdrh  CREATE INDEX t300x ON t300(a,b,c);
10657a8c615Sdrh  INSERT INTO t300 VALUES(0,1,99),(0,1,0),(0,0,0);
10757a8c615Sdrh  SELECT *,'.' FROM t300 WHERE a=0 AND (c=0 OR c=99) ORDER BY c DESC;
10857a8c615Sdrh} {0 1 99 . 0 0 0 . 0 1 0 .}
10957a8c615Sdrhdo_execsql_test limit2-310 {
11057a8c615Sdrh  SELECT *,'.' FROM t300 WHERE a=0 AND (c=0 OR c=99) ORDER BY c DESC LIMIT 1;
11157a8c615Sdrh} {0 1 99 .}
112dd545d3bSdrh
1138dd099bbSdrh# Make sure the SELECT loop is ordered correctly for the direction of
1148dd099bbSdrh# the ORDER BY
1158dd099bbSdrh#
1168dd099bbSdrhdo_execsql_test limit2-400 {
1178dd099bbSdrh  CREATE TABLE t400(a,b);
1188dd099bbSdrh  CREATE INDEX t400_ab ON t400(a,b);
1198dd099bbSdrh  INSERT INTO t400(a,b) VALUES(1,90),(1,40),(2,80),(2,30),(3,70),(3,20);
1208dd099bbSdrh  SELECT *,'x' FROM t400 WHERE a IN (1,2,3) ORDER BY b DESC LIMIT 3;
1218dd099bbSdrh  SELECT *,'y' FROM t400 WHERE a IN (1,2,3) ORDER BY +b DESC LIMIT 3;
1228dd099bbSdrh} {1 90 x 2 80 x 3 70 x 1 90 y 2 80 y 3 70 y}
12373fa4737Sdrh
12483465a66Sdan
12583465a66Sdando_execsql_test 500 {
12683465a66Sdan  CREATE TABLE t500(i INTEGER PRIMARY KEY, j);
12783465a66Sdan  INSERT INTO t500 VALUES(1, 1);
12883465a66Sdan  INSERT INTO t500 VALUES(2, 2);
12983465a66Sdan  INSERT INTO t500 VALUES(3, 3);
13083465a66Sdan  INSERT INTO t500 VALUES(4, 0);
13183465a66Sdan  INSERT INTO t500 VALUES(5, 5);
13283465a66Sdan  SELECT j FROM t500 WHERE i IN (1,2,3,4,5) ORDER BY j DESC LIMIT 3;
13383465a66Sdan} {5 3 2}
13483465a66Sdando_execsql_test 501 {
13583465a66Sdan  CREATE TABLE t501(i INTEGER PRIMARY KEY, j);
13683465a66Sdan  INSERT INTO t501 VALUES(1, 5);
13783465a66Sdan  INSERT INTO t501 VALUES(2, 4);
13883465a66Sdan  INSERT INTO t501 VALUES(3, 3);
13983465a66Sdan  INSERT INTO t501 VALUES(4, 6);
14083465a66Sdan  INSERT INTO t501 VALUES(5, 1);
14183465a66Sdan  SELECT j FROM t501 WHERE i IN (1,2,3,4,5) ORDER BY j LIMIT 3;
14283465a66Sdan} {1 3 4}
14383465a66Sdando_execsql_test 502 {
14483465a66Sdan  CREATE TABLE t502(i INT PRIMARY KEY, j);
14583465a66Sdan  INSERT INTO t502 VALUES(1, 5);
14683465a66Sdan  INSERT INTO t502 VALUES(2, 4);
14783465a66Sdan  INSERT INTO t502 VALUES(3, 3);
14883465a66Sdan  INSERT INTO t502 VALUES(4, 6);
14983465a66Sdan  INSERT INTO t502 VALUES(5, 1);
15083465a66Sdan  SELECT j FROM t502 WHERE i IN (1,2,3,4,5) ORDER BY j LIMIT 3;
15183465a66Sdan} {1 3 4}
15283465a66Sdan
153472e41eaSdrh# Ticket https://www.sqlite.org/src/info/123c9ba32130a6c9 2017-12-13
154472e41eaSdrh# Incorrect result when an idnex is used for an ordered join.
155472e41eaSdrh#
156472e41eaSdrh# This test case is in the limit2.test module because the problem was first
157472e41eaSdrh# exposed by check-in https://www.sqlite.org/src/info/559733b09e which
158472e41eaSdrh# implemented the ORDER BY LIMIT optimization that limit2.test strives to
159472e41eaSdrh# test.
160472e41eaSdrh#
161472e41eaSdrhdo_execsql_test 600 {
162472e41eaSdrh  DROP TABLE IF EXISTS t1;
163472e41eaSdrh  CREATE TABLE t1(a, b);  INSERT INTO t1 VALUES(1,2);
164472e41eaSdrh  DROP TABLE IF EXISTS t2;
165472e41eaSdrh  CREATE TABLE t2(x, y);  INSERT INTO t2 VALUES(1,3);
166472e41eaSdrh  CREATE INDEX t1ab ON t1(a,b);
167472e41eaSdrh  SELECT y FROM t1, t2 WHERE a=x AND b<=y ORDER BY b DESC;
168472e41eaSdrh} {3}
169472e41eaSdrh
170*6ee5a7b4Sdrh# Ticket https://www.sqlite.org/src/info/9936b2fa443fec03 2018-09-08
171*6ee5a7b4Sdrh# Infinite loop due to the ORDER BY LIMIT optimization.
172*6ee5a7b4Sdrh#
173*6ee5a7b4Sdrhdo_execsql_test 700 {
174*6ee5a7b4Sdrh  DROP TABLE IF EXISTS t1;
175*6ee5a7b4Sdrh  DROP TABLE IF EXISTS t2;
176*6ee5a7b4Sdrh  CREATE TABLE t1(aa VARCHAR PRIMARY KEY NOT NULL,bb,cc,x VARCHAR(400));
177*6ee5a7b4Sdrh  INSERT INTO t1(aa,bb,cc) VALUES('maroon','meal','lecture');
178*6ee5a7b4Sdrh  INSERT INTO t1(aa,bb,cc) VALUES('reality','meal','catsear');
179*6ee5a7b4Sdrh  CREATE TABLE t2(aa VARCHAR PRIMARY KEY, dd INT DEFAULT 1, ee, x VARCHAR(100));
180*6ee5a7b4Sdrh  INSERT INTO t2(aa,dd,ee) VALUES('maroon',0,'travel'),('reality',0,'hour');
181*6ee5a7b4Sdrh  CREATE INDEX t2x1 ON t2(dd,ee);
182*6ee5a7b4Sdrh  ANALYZE;
183*6ee5a7b4Sdrh  DROP TABLE IF EXISTS sqlite_stat4;
184*6ee5a7b4Sdrh  DELETE FROM sqlite_stat1;
185*6ee5a7b4Sdrh  INSERT INTO sqlite_stat1 VALUES
186*6ee5a7b4Sdrh    ('t2','t2x1','3 3 3'),
187*6ee5a7b4Sdrh    ('t2','sqlite_autoindex_t2_1','3 1'),
188*6ee5a7b4Sdrh    ('t1','sqlite_autoindex_t1_1','2 1');
189*6ee5a7b4Sdrh  ANALYZE sqlite_master;
190*6ee5a7b4Sdrh  SELECT *
191*6ee5a7b4Sdrh    FROM t1 LEFT JOIN t2 ON t1.aa=t2.aa
192*6ee5a7b4Sdrh   WHERE t1.bb='meal'
193*6ee5a7b4Sdrh   ORDER BY t2.dd DESC
194*6ee5a7b4Sdrh   LIMIT 1;
195*6ee5a7b4Sdrh} {maroon meal lecture {} maroon 0 travel {}}
196*6ee5a7b4Sdrhdo_execsql_test 710 {
197*6ee5a7b4Sdrh  DROP TABLE t1;
198*6ee5a7b4Sdrh  DROP TABLE t2;
199*6ee5a7b4Sdrh  CREATE TABLE t1(aa, bb);
200*6ee5a7b4Sdrh  INSERT INTO t1 VALUES('maroon','meal');
201*6ee5a7b4Sdrh  CREATE TABLE t2(cc, dd, ee, x VARCHAR(100));
202*6ee5a7b4Sdrh  INSERT INTO t2(cc,dd,ee) VALUES('maroon',1,'one');
203*6ee5a7b4Sdrh  INSERT INTO t2(cc,dd,ee) VALUES('maroon',2,'two');
204*6ee5a7b4Sdrh  INSERT INTO t2(cc,dd,ee) VALUES('maroon',0,'zero');
205*6ee5a7b4Sdrh  CREATE INDEX t2ddee ON t2(dd,ee);
206*6ee5a7b4Sdrh  CREATE INDEX t2cc ON t2(cc);
207*6ee5a7b4Sdrh   ANALYZE;
208*6ee5a7b4Sdrh  SELECT t2.cc, t2.dd, t2.ee FROM t1 CROSS JOIN t2 ON t1.aa=t2.cc
209*6ee5a7b4Sdrh  ORDER BY t2.dd LIMIT 1;
210*6ee5a7b4Sdrh} {maroon 0 zero}
211*6ee5a7b4Sdrhdo_execsql_test 720 {
212*6ee5a7b4Sdrh  SELECT t2.cc, t2.dd, t2.ee FROM t1 CROSS JOIN t2 ON t1.aa=t2.cc
213*6ee5a7b4Sdrh  WHERE t1.bb='meal'
214*6ee5a7b4Sdrh  ORDER BY t2.dd LIMIT 1;
215*6ee5a7b4Sdrh} {maroon 0 zero}
216*6ee5a7b4Sdrh
21773fa4737Sdrhfinish_test
218