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 LIMIT ... OFFSET ... clause
13 # of UPDATE and DELETE statements.
16 set testdir [file dirname $argv0]
17 source $testdir/tester.tcl
18 set testprefix wherelimit2
20 ifcapable !update_delete_limit {
25 #-------------------------------------------------------------------------
26 # Test with views and INSTEAD OF triggers.
29 CREATE TABLE t1(a, b);
30 INSERT INTO t1 VALUES(1, 'f');
31 INSERT INTO t1 VALUES(2, 'e');
32 INSERT INTO t1 VALUES(3, 'd');
33 INSERT INTO t1 VALUES(4, 'c');
34 INSERT INTO t1 VALUES(5, 'b');
35 INSERT INTO t1 VALUES(6, 'a');
37 CREATE VIEW v1 AS SELECT a,b FROM t1;
38 CREATE TABLE log(op, a);
40 CREATE TRIGGER v1del INSTEAD OF DELETE ON v1 BEGIN
41 INSERT INTO log VALUES('delete', old.a);
44 CREATE TRIGGER v1upd INSTEAD OF UPDATE ON v1 BEGIN
45 INSERT INTO log VALUES('update', old.a);
50 DELETE FROM v1 ORDER BY a LIMIT 3;
51 SELECT * FROM log; DELETE FROM log;
53 delete 1 delete 2 delete 3
56 DELETE FROM v1 ORDER BY b LIMIT 3;
57 SELECT * FROM log; DELETE FROM log;
59 delete 6 delete 5 delete 4
62 UPDATE v1 SET b = 555 ORDER BY a LIMIT 3;
63 SELECT * FROM log; DELETE FROM log;
65 update 1 update 2 update 3
68 UPDATE v1 SET b = 555 ORDER BY b LIMIT 3;
69 SELECT * FROM log; DELETE FROM log;
71 update 6 update 5 update 4
74 #-------------------------------------------------------------------------
75 # Simple test using WITHOUT ROWID table.
77 do_execsql_test 2.1.0 {
78 CREATE TABLE t2(a, b, c, PRIMARY KEY(a, b)) WITHOUT ROWID;
79 INSERT INTO t2 VALUES(1, 1, 'h');
80 INSERT INTO t2 VALUES(1, 2, 'g');
81 INSERT INTO t2 VALUES(2, 1, 'f');
82 INSERT INTO t2 VALUES(2, 2, 'e');
83 INSERT INTO t2 VALUES(3, 1, 'd');
84 INSERT INTO t2 VALUES(3, 2, 'c');
85 INSERT INTO t2 VALUES(4, 1, 'b');
86 INSERT INTO t2 VALUES(4, 2, 'a');
89 do_execsql_test 2.1.1 {
91 DELETE FROM t2 WHERE b=1 ORDER BY c LIMIT 2;
92 SELECT c FROM t2 ORDER BY 1;
96 do_execsql_test 2.1.2 {
98 UPDATE t2 SET c=NULL ORDER BY a, b DESC LIMIT 3 OFFSET 1;
99 SELECT a, b, c FROM t2;
112 do_execsql_test 2.2.0 {
114 CREATE TABLE t2(a INTEGER PRIMARY KEY, b, c) WITHOUT ROWID;
115 INSERT INTO t2 VALUES(1, 1, 'h');
116 INSERT INTO t2 VALUES(2, 2, 'g');
117 INSERT INTO t2 VALUES(3, 1, 'f');
118 INSERT INTO t2 VALUES(4, 2, 'e');
119 INSERT INTO t2 VALUES(5, 1, 'd');
120 INSERT INTO t2 VALUES(6, 2, 'c');
121 INSERT INTO t2 VALUES(7, 1, 'b');
122 INSERT INTO t2 VALUES(8, 2, 'a');
125 do_execsql_test 2.2.1 {
127 DELETE FROM t2 WHERE b=1 ORDER BY c LIMIT 2;
128 SELECT c FROM t2 ORDER BY 1;
132 do_execsql_test 2.2.2 {
134 UPDATE t2 SET c=NULL ORDER BY a DESC LIMIT 3 OFFSET 1;
135 SELECT a, b, c FROM t2;
148 #-------------------------------------------------------------------------
149 # Test using a virtual table
152 do_execsql_test 3.0 {
153 CREATE VIRTUAL TABLE ft USING fts5(x);
154 INSERT INTO ft(rowid, x) VALUES(-45, 'a a');
155 INSERT INTO ft(rowid, x) VALUES(12, 'a b');
156 INSERT INTO ft(rowid, x) VALUES(444, 'a c');
157 INSERT INTO ft(rowid, x) VALUES(12300, 'a d');
158 INSERT INTO ft(rowid, x) VALUES(25400, 'a c');
159 INSERT INTO ft(rowid, x) VALUES(25401, 'a b');
160 INSERT INTO ft(rowid, x) VALUES(50000, 'a a');
163 do_execsql_test 3.1.1 {
165 DELETE FROM ft ORDER BY rowid LIMIT 3;
168 } {{a d} {a c} {a b} {a a}}
170 do_execsql_test 3.1.2 {
172 DELETE FROM ft WHERE ft MATCH 'a' ORDER BY rowid LIMIT 3;
175 } {{a d} {a c} {a b} {a a}}
177 do_execsql_test 3.1.3 {
179 DELETE FROM ft WHERE ft MATCH 'b' ORDER BY rowid ASC LIMIT 1 OFFSET 1;
180 SELECT rowid FROM ft;
182 } {-45 12 444 12300 25400 50000}
184 do_execsql_test 3.2.1 {
186 UPDATE ft SET x='hello' ORDER BY rowid LIMIT 2 OFFSET 2;
189 } {{a a} {a b} hello hello {a c} {a b} {a a}}
191 do_execsql_test 3.2.2 {
193 UPDATE ft SET x='hello' WHERE ft MATCH 'a'
194 ORDER BY rowid DESC LIMIT 2 OFFSET 2;
197 } {{a a} {a b} {a c} hello hello {a b} {a a}}
200 #-------------------------------------------------------------------------
201 # Test using INDEXED BY clauses.
203 do_execsql_test 4.0 {
204 CREATE TABLE x1(a INTEGER PRIMARY KEY, b, c, d);
205 CREATE INDEX x1bc ON x1(b, c);
206 INSERT INTO x1 VALUES(1,1,1,1);
207 INSERT INTO x1 VALUES(2,1,2,2);
208 INSERT INTO x1 VALUES(3,2,1,3);
209 INSERT INTO x1 VALUES(4,2,2,3);
210 INSERT INTO x1 VALUES(5,3,1,2);
211 INSERT INTO x1 VALUES(6,3,2,1);
214 do_execsql_test 4.1 {
216 DELETE FROM x1 ORDER BY a LIMIT 2;
221 # 2020-06-03: Query planner improved so that a solution is possible.
223 #do_catchsql_test 4.2 {
224 # DELETE FROM x1 INDEXED BY x1bc WHERE d=3 LIMIT 1;
225 #} {1 {no query solution}}
227 do_execsql_test 4.3 {
228 DELETE FROM x1 INDEXED BY x1bc WHERE b=3 LIMIT 1;
232 # 2020-06-03: Query planner improved so that a solution is possible.
234 #do_catchsql_test 4.4 {
235 # UPDATE x1 INDEXED BY x1bc SET d=5 WHERE d=3 LIMIT 1;
236 #} {1 {no query solution}}
238 do_execsql_test 4.5 {
239 UPDATE x1 INDEXED BY x1bc SET d=5 WHERE b=2 LIMIT 1;
241 } {1 1 2 2 3 5 4 3 6 1}
243 #-------------------------------------------------------------------------
244 # Test using object names that require quoting.
246 do_execsql_test 5.0 {
247 CREATE TABLE "x y"("a b" PRIMARY KEY, "c d") WITHOUT ROWID;
248 CREATE INDEX xycd ON "x y"("c d");
250 INSERT INTO "x y" VALUES('a', 'a');
251 INSERT INTO "x y" VALUES('b', 'b');
252 INSERT INTO "x y" VALUES('c', 'c');
253 INSERT INTO "x y" VALUES('d', 'd');
254 INSERT INTO "x y" VALUES('e', 'a');
255 INSERT INTO "x y" VALUES('f', 'b');
256 INSERT INTO "x y" VALUES('g', 'c');
257 INSERT INTO "x y" VALUES('h', 'd');
260 do_execsql_test 5.1 {
262 DELETE FROM "x y" WHERE "c d"!='e' ORDER BY "c d" LIMIT 2 OFFSET 2;
263 SELECT * FROM "x y" ORDER BY 1;
266 a a c c d d e a g c h d
269 do_execsql_test 5.2 {
271 UPDATE "x y" SET "c d"='e' WHERE "c d"!='e' ORDER BY "c d" LIMIT 2 OFFSET 2;
272 SELECT * FROM "x y" ORDER BY 1;
275 a a b e c c d d e a f e g c h d
278 proc log {args} { lappend ::log {*}$args }
280 do_execsql_test 5.3 {
281 CREATE VIEW "v w" AS SELECT * FROM "x y";
282 CREATE TRIGGER tr1 INSTEAD OF DELETE ON "v w" BEGIN
283 SELECT log(old."a b", old."c d");
285 CREATE TRIGGER tr2 INSTEAD OF UPDATE ON "v w" BEGIN
286 SELECT log(new."a b", new."c d");
292 execsql { DELETE FROM "v w" ORDER BY "a b" LIMIT 3 }
298 execsql { UPDATE "v w" SET "a b" = "a b" || 'x' ORDER BY "a b" LIMIT 5; }
300 } {ax a bx b cx c dx d ex a}
302 #-----------------------------------------------------------------------
304 do_execsql_test 6.0 {
306 INSERT INTO t2(x) VALUES(1),(2),(3),(5),(8),(13);
309 do_execsql_test 6.1 {
310 WITH t2 AS MATERIALIZED (VALUES(5))
311 DELETE FROM t2 ORDER BY rank()OVER() LIMIT 2;
314 do_execsql_test 6.2 {
318 #-------------------------------------------------------------------------
320 do_execsql_test 7.0 {
321 CREATE TABLE t1(a INT); INSERT INTO t1(a) VALUES(0);
324 do_execsql_test 7.1 {
325 WITH t1(b) AS (SELECT * FROM (SELECT * FROM (VALUES(2))))
326 UPDATE t1 SET a=3 LIMIT 1;
329 do_execsql_test 7.2 {