1# 2001 November 6 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 ... OFFSET ... clause 13# of SELECT statements. 14# 15# $Id: limit.test,v 1.24 2005/02/05 12:48:49 danielk1977 Exp $ 16 17set testdir [file dirname $argv0] 18source $testdir/tester.tcl 19 20# Build some test data 21# 22execsql { 23 CREATE TABLE t1(x int, y int); 24 BEGIN; 25} 26for {set i 1} {$i<=32} {incr i} { 27 for {set j 0} {pow(2,$j)<$i} {incr j} {} 28 execsql "INSERT INTO t1 VALUES([expr {32-$i}],[expr {10-$j}])" 29} 30execsql { 31 COMMIT; 32} 33 34do_test limit-1.0 { 35 execsql {SELECT count(*) FROM t1} 36} {32} 37do_test limit-1.1 { 38 execsql {SELECT count(*) FROM t1 LIMIT 5} 39} {32} 40do_test limit-1.2.1 { 41 execsql {SELECT x FROM t1 ORDER BY x LIMIT 5} 42} {0 1 2 3 4} 43do_test limit-1.2.2 { 44 execsql {SELECT x FROM t1 ORDER BY x LIMIT 5 OFFSET 2} 45} {2 3 4 5 6} 46do_test limit-1.2.3 { 47 execsql {SELECT x FROM t1 ORDER BY x LIMIT 2, 5} 48} {2 3 4 5 6} 49do_test limit-1.3 { 50 execsql {SELECT x FROM t1 ORDER BY x LIMIT 5 OFFSET 5} 51} {5 6 7 8 9} 52do_test limit-1.4.1 { 53 execsql {SELECT x FROM t1 ORDER BY x LIMIT 50 OFFSET 30} 54} {30 31} 55do_test limit-1.4.2 { 56 execsql {SELECT x FROM t1 ORDER BY x LIMIT 30, 50} 57} {30 31} 58do_test limit-1.5 { 59 execsql {SELECT x FROM t1 ORDER BY x LIMIT 50 OFFSET 50} 60} {} 61do_test limit-1.6 { 62 execsql {SELECT * FROM t1 AS a, t1 AS b ORDER BY a.x, b.x LIMIT 5} 63} {0 5 0 5 0 5 1 5 0 5 2 5 0 5 3 5 0 5 4 5} 64do_test limit-1.7 { 65 execsql {SELECT * FROM t1 AS a, t1 AS b ORDER BY a.x, b.x LIMIT 5 OFFSET 32} 66} {1 5 0 5 1 5 1 5 1 5 2 5 1 5 3 5 1 5 4 5} 67 68ifcapable {view && subquery} { 69 do_test limit-2.1 { 70 execsql { 71 CREATE VIEW v1 AS SELECT * FROM t1 LIMIT 2; 72 SELECT count(*) FROM (SELECT * FROM v1); 73 } 74 } 2 75} ;# ifcapable view 76do_test limit-2.2 { 77 execsql { 78 CREATE TABLE t2 AS SELECT * FROM t1 LIMIT 2; 79 SELECT count(*) FROM t2; 80 } 81} 2 82ifcapable subquery { 83 do_test limit-2.3 { 84 execsql { 85 SELECT count(*) FROM t1 WHERE rowid IN (SELECT rowid FROM t1 LIMIT 2); 86 } 87 } 2 88} 89 90ifcapable subquery { 91 do_test limit-3.1 { 92 execsql { 93 SELECT z FROM (SELECT y*10+x AS z FROM t1 ORDER BY x LIMIT 10) 94 ORDER BY z LIMIT 5; 95 } 96 } {50 51 52 53 54} 97} 98 99do_test limit-4.1 { 100 ifcapable subquery { 101 execsql { 102 BEGIN; 103 CREATE TABLE t3(x); 104 INSERT INTO t3 SELECT x FROM t1 ORDER BY x LIMIT 10 OFFSET 1; 105 INSERT INTO t3 SELECT x+(SELECT max(x) FROM t3) FROM t3; 106 INSERT INTO t3 SELECT x+(SELECT max(x) FROM t3) FROM t3; 107 INSERT INTO t3 SELECT x+(SELECT max(x) FROM t3) FROM t3; 108 INSERT INTO t3 SELECT x+(SELECT max(x) FROM t3) FROM t3; 109 INSERT INTO t3 SELECT x+(SELECT max(x) FROM t3) FROM t3; 110 INSERT INTO t3 SELECT x+(SELECT max(x) FROM t3) FROM t3; 111 INSERT INTO t3 SELECT x+(SELECT max(x) FROM t3) FROM t3; 112 INSERT INTO t3 SELECT x+(SELECT max(x) FROM t3) FROM t3; 113 INSERT INTO t3 SELECT x+(SELECT max(x) FROM t3) FROM t3; 114 INSERT INTO t3 SELECT x+(SELECT max(x) FROM t3) FROM t3; 115 END; 116 SELECT count(*) FROM t3; 117 } 118 } else { 119 execsql { 120 BEGIN; 121 CREATE TABLE t3(x); 122 INSERT INTO t3 SELECT x FROM t1 ORDER BY x LIMIT 10 OFFSET 1; 123 } 124 for {set i 0} {$i<10} {incr i} { 125 set max_x_t3 [execsql {SELECT max(x) FROM t3}] 126 execsql "INSERT INTO t3 SELECT x+$max_x_t3 FROM t3;" 127 } 128 execsql { 129 END; 130 SELECT count(*) FROM t3; 131 } 132 } 133} {10240} 134do_test limit-4.2 { 135 execsql { 136 SELECT x FROM t3 LIMIT 2 OFFSET 10000 137 } 138} {10001 10002} 139do_test limit-4.3 { 140 execsql { 141 CREATE TABLE t4 AS SELECT x, 142 'abcdefghijklmnopqrstuvwyxz ABCDEFGHIJKLMNOPQRSTUVWYXZ' || x || 143 'abcdefghijklmnopqrstuvwyxz ABCDEFGHIJKLMNOPQRSTUVWYXZ' || x || 144 'abcdefghijklmnopqrstuvwyxz ABCDEFGHIJKLMNOPQRSTUVWYXZ' || x || 145 'abcdefghijklmnopqrstuvwyxz ABCDEFGHIJKLMNOPQRSTUVWYXZ' || x || 146 'abcdefghijklmnopqrstuvwyxz ABCDEFGHIJKLMNOPQRSTUVWYXZ' || x AS y 147 FROM t3 LIMIT 1000; 148 SELECT x FROM t4 ORDER BY y DESC LIMIT 1 OFFSET 999; 149 } 150} {1000} 151 152do_test limit-5.1 { 153 execsql { 154 CREATE TABLE t5(x,y); 155 INSERT INTO t5 SELECT x-y, x+y FROM t1 WHERE x BETWEEN 10 AND 15 156 ORDER BY x LIMIT 2; 157 SELECT * FROM t5 ORDER BY x; 158 } 159} {5 15 6 16} 160do_test limit-5.2 { 161 execsql { 162 DELETE FROM t5; 163 INSERT INTO t5 SELECT x-y, x+y FROM t1 WHERE x BETWEEN 10 AND 15 164 ORDER BY x DESC LIMIT 2; 165 SELECT * FROM t5 ORDER BY x; 166 } 167} {9 19 10 20} 168do_test limit-5.3 { 169 execsql { 170 DELETE FROM t5; 171 INSERT INTO t5 SELECT x-y, x+y FROM t1 WHERE x ORDER BY x DESC LIMIT 31; 172 SELECT * FROM t5 ORDER BY x LIMIT 2; 173 } 174} {-4 6 -3 7} 175do_test limit-5.4 { 176 execsql { 177 SELECT * FROM t5 ORDER BY x DESC, y DESC LIMIT 2; 178 } 179} {21 41 21 39} 180do_test limit-5.5 { 181 execsql { 182 DELETE FROM t5; 183 INSERT INTO t5 SELECT a.x*100+b.x, a.y*100+b.y FROM t1 AS a, t1 AS b 184 ORDER BY 1, 2 LIMIT 1000; 185 SELECT count(*), sum(x), sum(y), min(x), max(x), min(y), max(y) FROM t5; 186 } 187} {1000 1528204.0 593161.0 0 3107 505 1005} 188 189# There is some contraversy about whether LIMIT 0 should be the same as 190# no limit at all or if LIMIT 0 should result in zero output rows. 191# 192do_test limit-6.1 { 193 execsql { 194 BEGIN; 195 CREATE TABLE t6(a); 196 INSERT INTO t6 VALUES(1); 197 INSERT INTO t6 VALUES(2); 198 INSERT INTO t6 SELECT a+2 FROM t6; 199 COMMIT; 200 SELECT * FROM t6; 201 } 202} {1 2 3 4} 203do_test limit-6.2 { 204 execsql { 205 SELECT * FROM t6 LIMIT -1 OFFSET -1; 206 } 207} {1 2 3 4} 208do_test limit-6.3 { 209 execsql { 210 SELECT * FROM t6 LIMIT 2 OFFSET -123; 211 } 212} {1 2} 213do_test limit-6.4 { 214 execsql { 215 SELECT * FROM t6 LIMIT -432 OFFSET 2; 216 } 217} {3 4} 218do_test limit-6.5 { 219 execsql { 220 SELECT * FROM t6 LIMIT -1 221 } 222} {1 2 3 4} 223do_test limit-6.6 { 224 execsql { 225 SELECT * FROM t6 LIMIT -1 OFFSET 1 226 } 227} {2 3 4} 228do_test limit-6.7 { 229 execsql { 230 SELECT * FROM t6 LIMIT 0 231 } 232} {} 233do_test limit-6.8 { 234 execsql { 235 SELECT * FROM t6 LIMIT 0 OFFSET 1 236 } 237} {} 238 239# Make sure LIMIT works well with compound SELECT statements. 240# Ticket #393 241# 242ifcapable compound { 243do_test limit-7.1.1 { 244 catchsql { 245 SELECT x FROM t2 LIMIT 5 UNION ALL SELECT a FROM t6; 246 } 247} {1 {LIMIT clause should come after UNION ALL not before}} 248do_test limit-7.1.2 { 249 catchsql { 250 SELECT x FROM t2 LIMIT 5 UNION SELECT a FROM t6; 251 } 252} {1 {LIMIT clause should come after UNION not before}} 253do_test limit-7.1.3 { 254 catchsql { 255 SELECT x FROM t2 LIMIT 5 EXCEPT SELECT a FROM t6 LIMIT 3; 256 } 257} {1 {LIMIT clause should come after EXCEPT not before}} 258do_test limit-7.1.4 { 259 catchsql { 260 SELECT x FROM t2 LIMIT 0,5 INTERSECT SELECT a FROM t6; 261 } 262} {1 {LIMIT clause should come after INTERSECT not before}} 263do_test limit-7.2 { 264 execsql { 265 SELECT x FROM t2 UNION ALL SELECT a FROM t6 LIMIT 5; 266 } 267} {31 30 1 2 3} 268do_test limit-7.3 { 269 execsql { 270 SELECT x FROM t2 UNION ALL SELECT a FROM t6 LIMIT 3 OFFSET 1; 271 } 272} {30 1 2} 273do_test limit-7.4 { 274 execsql { 275 SELECT x FROM t2 UNION ALL SELECT a FROM t6 ORDER BY 1 LIMIT 3 OFFSET 1; 276 } 277} {2 3 4} 278do_test limit-7.5 { 279 execsql { 280 SELECT x FROM t2 UNION SELECT x+2 FROM t2 LIMIT 2 OFFSET 1; 281 } 282} {31 32} 283do_test limit-7.6 { 284 execsql { 285 SELECT x FROM t2 UNION SELECT x+2 FROM t2 ORDER BY 1 DESC LIMIT 2 OFFSET 1; 286 } 287} {32 31} 288do_test limit-7.7 { 289 execsql { 290 SELECT a+9 FROM t6 EXCEPT SELECT y FROM t2 LIMIT 2; 291 } 292} {11 12} 293do_test limit-7.8 { 294 execsql { 295 SELECT a+9 FROM t6 EXCEPT SELECT y FROM t2 ORDER BY 1 DESC LIMIT 2; 296 } 297} {13 12} 298do_test limit-7.9 { 299 execsql { 300 SELECT a+26 FROM t6 INTERSECT SELECT x FROM t2 LIMIT 1; 301 } 302} {30} 303do_test limit-7.10 { 304 execsql { 305 SELECT a+27 FROM t6 INTERSECT SELECT x FROM t2 LIMIT 1; 306 } 307} {30} 308do_test limit-7.11 { 309 execsql { 310 SELECT a+27 FROM t6 INTERSECT SELECT x FROM t2 LIMIT 1 OFFSET 1; 311 } 312} {31} 313do_test limit-7.12 { 314 execsql { 315 SELECT a+27 FROM t6 INTERSECT SELECT x FROM t2 316 ORDER BY 1 DESC LIMIT 1 OFFSET 1; 317 } 318} {30} 319} ;# ifcapable compound 320 321# Tests for limit in conjunction with distinct. The distinct should 322# occur before both the limit and the offset. Ticket #749. 323# 324do_test limit-8.1 { 325 execsql { 326 SELECT DISTINCT round(x/100) FROM t3 LIMIT 5; 327 } 328} {0 1 2 3 4} 329do_test limit-8.2 { 330 execsql { 331 SELECT DISTINCT round(x/100) FROM t3 LIMIT 5 OFFSET 5; 332 } 333} {5 6 7 8 9} 334do_test limit-8.3 { 335 execsql { 336 SELECT DISTINCT round(x/100) FROM t3 LIMIT 5 OFFSET 25; 337 } 338} {25 26 27 28 29} 339 340# Make sure limits on multiple subqueries work correctly. 341# Ticket #1035 342# 343ifcapable subquery { 344 do_test limit-9.1 { 345 execsql { 346 SELECT * FROM (SELECT * FROM t6 LIMIT 3); 347 } 348 } {1 2 3} 349} 350do_test limit-9.2.1 { 351 execsql { 352 CREATE TABLE t7 AS SELECT * FROM t6; 353 } 354} {} 355ifcapable subquery { 356 do_test limit-9.2.2 { 357 execsql { 358 SELECT * FROM (SELECT * FROM t7 LIMIT 3); 359 } 360 } {1 2 3} 361} 362ifcapable compound { 363 ifcapable subquery { 364 do_test limit-9.3 { 365 execsql { 366 SELECT * FROM (SELECT * FROM t6 LIMIT 3) 367 UNION 368 SELECT * FROM (SELECT * FROM t7 LIMIT 3) 369 ORDER BY 1 370 } 371 } {1 2 3} 372 do_test limit-9.4 { 373 execsql { 374 SELECT * FROM (SELECT * FROM t6 LIMIT 3) 375 UNION 376 SELECT * FROM (SELECT * FROM t7 LIMIT 3) 377 ORDER BY 1 378 LIMIT 2 379 } 380 } {1 2} 381 } 382 do_test limit-9.5 { 383 catchsql { 384 SELECT * FROM t6 LIMIT 3 385 UNION 386 SELECT * FROM t7 LIMIT 3 387 } 388 } {1 {LIMIT clause should come after UNION not before}} 389} 390 391# Test LIMIT and OFFSET using SQL variables. 392do_test limit-10.1 { 393 set limit 10 394 db eval { 395 SELECT x FROM t1 LIMIT $limit; 396 } 397} {31 30 29 28 27 26 25 24 23 22} 398do_test limit-10.2 { 399 set limit 5 400 set offset 5 401 db eval { 402 SELECT x FROM t1 LIMIT $limit OFFSET $offset; 403 } 404} {26 25 24 23 22} 405do_test limit-10.3 { 406 set limit -1 407 db eval { 408 SELECT x FROM t1 WHERE x<10 LIMIT $limit; 409 } 410} {9 8 7 6 5 4 3 2 1 0} 411do_test limit-10.4 { 412 set limit 1.5 413 set rc [catch { 414 db eval { 415 SELECT x FROM t1 WHERE x<10 LIMIT $limit; 416 } } msg] 417 list $rc $msg 418} {1 {datatype mismatch}} 419do_test limit-10.5 { 420 set limit "hello world" 421 set rc [catch { 422 db eval { 423 SELECT x FROM t1 WHERE x<10 LIMIT $limit; 424 } } msg] 425 list $rc $msg 426} {1 {datatype mismatch}} 427 428finish_test 429