xref: /sqlite-3.40.0/test/e_update.test (revision b3366b99)
1af1dcab2Sdan# 2010 September 20
2af1dcab2Sdan#
3af1dcab2Sdan# The author disclaims copyright to this source code.  In place of
4af1dcab2Sdan# a legal notice, here is a blessing:
5af1dcab2Sdan#
6af1dcab2Sdan#    May you do good and not evil.
7af1dcab2Sdan#    May you find forgiveness for yourself and forgive others.
8af1dcab2Sdan#    May you share freely, never taking more than you give.
9af1dcab2Sdan#
10af1dcab2Sdan#***********************************************************************
11af1dcab2Sdan#
12af1dcab2Sdan# This file implements tests to verify that the "testable statements" in
13af1dcab2Sdan# the lang_update.html document are correct.
14af1dcab2Sdan#
15af1dcab2Sdanset testdir [file dirname $argv0]
16af1dcab2Sdansource $testdir/tester.tcl
17af1dcab2Sdan
18b04757adSdan#--------------------
19b04757adSdan# Test organization:
20b04757adSdan#
21b04757adSdan#   e_update-1.*: Test statements describing the workings of UPDATE statements.
22b04757adSdan#
23b04757adSdan#   e_update-2.*: Test the restrictions on the UPDATE statement syntax that
24b04757adSdan#                 can be used within triggers.
25b04757adSdan#
26b04757adSdan#   e_update-3.*: Test the special LIMIT/OFFSET and ORDER BY clauses that can
27b04757adSdan#                 be used with UPDATE when SQLite is compiled with
28b04757adSdan#                 SQLITE_ENABLE_UPDATE_DELETE_LIMIT.
29b04757adSdan#
30b04757adSdan
31af1dcab2Sdanforcedelete test.db2
32af1dcab2Sdan
33af1dcab2Sdando_execsql_test e_update-0.0 {
34af1dcab2Sdan  ATTACH 'test.db2' AS aux;
35b04757adSdan  CREATE TABLE t1(a, b);
36af1dcab2Sdan  CREATE TABLE t2(a, b, c);
37af1dcab2Sdan  CREATE TABLE t3(a, b UNIQUE);
38b04757adSdan  CREATE TABLE t6(x, y);
39b04757adSdan  CREATE INDEX i1 ON t1(a);
40b04757adSdan
41b04757adSdan  CREATE TEMP TABLE t4(x, y);
42b04757adSdan  CREATE TEMP TABLE t6(x, y);
43b04757adSdan
44b04757adSdan  CREATE TABLE aux.t1(a, b);
45b04757adSdan  CREATE TABLE aux.t5(a, b);
46af1dcab2Sdan} {}
47af1dcab2Sdan
48af1dcab2Sdanproc do_update_tests {args} {
49af1dcab2Sdan  uplevel do_select_tests $args
50af1dcab2Sdan}
51af1dcab2Sdan
5239759747Sdrh# -- syntax diagram update-stmt
53af1dcab2Sdan#
54af1dcab2Sdando_update_tests e_update-0 {
55af1dcab2Sdan  1    "UPDATE t1 SET a=10" {}
56af1dcab2Sdan  2    "UPDATE t1 SET a=10, b=5" {}
57af1dcab2Sdan  3    "UPDATE t1 SET a=10 WHERE b=5" {}
58af1dcab2Sdan  4    "UPDATE t1 SET b=5,a=10 WHERE 1" {}
59af1dcab2Sdan  5    "UPDATE main.t1 SET a=10" {}
60af1dcab2Sdan  6    "UPDATE main.t1 SET a=10, b=5" {}
61af1dcab2Sdan  7    "UPDATE main.t1 SET a=10 WHERE b=5" {}
62af1dcab2Sdan  9    "UPDATE OR ROLLBACK t1 SET a=10" {}
63af1dcab2Sdan  10   "UPDATE OR ROLLBACK t1 SET a=10, b=5" {}
64af1dcab2Sdan  11   "UPDATE OR ROLLBACK t1 SET a=10 WHERE b=5" {}
65af1dcab2Sdan  12   "UPDATE OR ROLLBACK t1 SET b=5,a=10 WHERE 1" {}
66af1dcab2Sdan  13   "UPDATE OR ROLLBACK main.t1 SET a=10" {}
67af1dcab2Sdan  14   "UPDATE OR ROLLBACK main.t1 SET a=10, b=5" {}
68af1dcab2Sdan  15   "UPDATE OR ROLLBACK main.t1 SET a=10 WHERE b=5" {}
69af1dcab2Sdan  16   "UPDATE OR ROLLBACK main.t1 SET b=5,a=10 WHERE 1" {}
70af1dcab2Sdan  17   "UPDATE OR ABORT t1 SET a=10" {}
71af1dcab2Sdan  18   "UPDATE OR ABORT t1 SET a=10, b=5" {}
72af1dcab2Sdan  19   "UPDATE OR ABORT t1 SET a=10 WHERE b=5" {}
73af1dcab2Sdan  20   "UPDATE OR ABORT t1 SET b=5,a=10 WHERE 1" {}
74af1dcab2Sdan  21   "UPDATE OR ABORT main.t1 SET a=10" {}
75af1dcab2Sdan  22   "UPDATE OR ABORT main.t1 SET a=10, b=5" {}
76af1dcab2Sdan  23   "UPDATE OR ABORT main.t1 SET a=10 WHERE b=5" {}
77af1dcab2Sdan  24   "UPDATE OR ABORT main.t1 SET b=5,a=10 WHERE 1" {}
78af1dcab2Sdan  25   "UPDATE OR REPLACE t1 SET a=10" {}
79af1dcab2Sdan  26   "UPDATE OR REPLACE t1 SET a=10, b=5" {}
80af1dcab2Sdan  27   "UPDATE OR REPLACE t1 SET a=10 WHERE b=5" {}
81af1dcab2Sdan  28   "UPDATE OR REPLACE t1 SET b=5,a=10 WHERE 1" {}
82af1dcab2Sdan  29   "UPDATE OR REPLACE main.t1 SET a=10" {}
83af1dcab2Sdan  30   "UPDATE OR REPLACE main.t1 SET a=10, b=5" {}
84af1dcab2Sdan  31   "UPDATE OR REPLACE main.t1 SET a=10 WHERE b=5" {}
85af1dcab2Sdan  32   "UPDATE OR REPLACE main.t1 SET b=5,a=10 WHERE 1" {}
86af1dcab2Sdan  33   "UPDATE OR FAIL t1 SET a=10" {}
87af1dcab2Sdan  34   "UPDATE OR FAIL t1 SET a=10, b=5" {}
88af1dcab2Sdan  35   "UPDATE OR FAIL t1 SET a=10 WHERE b=5" {}
89af1dcab2Sdan  36   "UPDATE OR FAIL t1 SET b=5,a=10 WHERE 1" {}
90af1dcab2Sdan  37   "UPDATE OR FAIL main.t1 SET a=10" {}
91af1dcab2Sdan  38   "UPDATE OR FAIL main.t1 SET a=10, b=5" {}
92af1dcab2Sdan  39   "UPDATE OR FAIL main.t1 SET a=10 WHERE b=5" {}
93af1dcab2Sdan  40   "UPDATE OR FAIL main.t1 SET b=5,a=10 WHERE 1" {}
94af1dcab2Sdan  41   "UPDATE OR IGNORE t1 SET a=10" {}
95af1dcab2Sdan  42   "UPDATE OR IGNORE t1 SET a=10, b=5" {}
96af1dcab2Sdan  43   "UPDATE OR IGNORE t1 SET a=10 WHERE b=5" {}
97af1dcab2Sdan  44   "UPDATE OR IGNORE t1 SET b=5,a=10 WHERE 1" {}
98af1dcab2Sdan  45   "UPDATE OR IGNORE main.t1 SET a=10" {}
99af1dcab2Sdan  46   "UPDATE OR IGNORE main.t1 SET a=10, b=5" {}
100af1dcab2Sdan  47   "UPDATE OR IGNORE main.t1 SET a=10 WHERE b=5" {}
101af1dcab2Sdan  48   "UPDATE OR IGNORE main.t1 SET b=5,a=10 WHERE 1" {}
102af1dcab2Sdan}
103af1dcab2Sdan
104af1dcab2Sdan# EVIDENCE-OF: R-38515-45264 An UPDATE statement is used to modify a
105af1dcab2Sdan# subset of the values stored in zero or more rows of the database table
106af1dcab2Sdan# identified by the qualified-table-name specified as part of the UPDATE
107af1dcab2Sdan# statement.
108af1dcab2Sdan#
109af1dcab2Sdan#     Test cases e_update-1.1.1.* test the "identified by the
110af1dcab2Sdan#     qualified-table-name" part of the statement above. Tests
111af1dcab2Sdan#     e_update-1.1.2.* show that the "zero or more rows" part is
112af1dcab2Sdan#     accurate.
113af1dcab2Sdan#
114af1dcab2Sdando_execsql_test e_update-1.1.0 {
115af1dcab2Sdan  INSERT INTO main.t1 VALUES(1, 'i');
116af1dcab2Sdan  INSERT INTO main.t1 VALUES(2, 'ii');
117af1dcab2Sdan  INSERT INTO main.t1 VALUES(3, 'iii');
118af1dcab2Sdan
119af1dcab2Sdan  INSERT INTO aux.t1 VALUES(1, 'I');
120af1dcab2Sdan  INSERT INTO aux.t1 VALUES(2, 'II');
121af1dcab2Sdan  INSERT INTO aux.t1 VALUES(3, 'III');
122af1dcab2Sdan} {}
123af1dcab2Sdando_update_tests e_update-1.1 {
124af1dcab2Sdan  1.1  "UPDATE t1 SET a = a+1; SELECT * FROM t1"             {2 i  3 ii  4 iii}
125af1dcab2Sdan  1.2  "UPDATE main.t1 SET a = a+1; SELECT * FROM main.t1"   {3 i  4 ii  5 iii}
126af1dcab2Sdan  1.3  "UPDATE aux.t1 SET a = a+1; SELECT * FROM aux.t1"     {2 I  3 II  4 III}
127af1dcab2Sdan
128af1dcab2Sdan  2.1  "UPDATE t1 SET a = a+1 WHERE a = 1; SELECT * FROM t1" {3 i  4 ii  5 iii}
129af1dcab2Sdan  2.2  "UPDATE t1 SET a = a+1 WHERE a = 4; SELECT * FROM t1" {3 i  5 ii  5 iii}
130af1dcab2Sdan}
131af1dcab2Sdan
132af1dcab2Sdan# EVIDENCE-OF: R-55869-30521 If the UPDATE statement does not have a
133af1dcab2Sdan# WHERE clause, all rows in the table are modified by the UPDATE.
134af1dcab2Sdan#
135af1dcab2Sdando_execsql_test e_update-1.2.0 {
136af1dcab2Sdan  DELETE FROM main.t1;
137af1dcab2Sdan  INSERT INTO main.t1 VALUES(1, 'i');
138af1dcab2Sdan  INSERT INTO main.t1 VALUES(2, 'ii');
139af1dcab2Sdan  INSERT INTO main.t1 VALUES(3, 'iii');
140af1dcab2Sdan} {}
141af1dcab2Sdando_update_tests e_update-1.2 {
142af1dcab2Sdan  1  "UPDATE t1 SET b = 'roman' ; SELECT * FROM t1"
143af1dcab2Sdan     {1 roman  2 roman  3 roman}
144af1dcab2Sdan
145af1dcab2Sdan  2  "UPDATE t1 SET a = 'greek' ; SELECT * FROM t1"
146af1dcab2Sdan     {greek roman  greek roman  greek roman}
147af1dcab2Sdan}
148af1dcab2Sdan
149*b3366b99Sdrh# EVIDENCE-OF: R-58095-46013 Otherwise, the UPDATE affects only those
150*b3366b99Sdrh# rows for which the WHERE clause boolean expression is true.
151af1dcab2Sdan#
152af1dcab2Sdando_execsql_test e_update-1.3.0 {
153af1dcab2Sdan  DELETE FROM main.t1;
154af1dcab2Sdan  INSERT INTO main.t1 VALUES(NULL, '');
155af1dcab2Sdan  INSERT INTO main.t1 VALUES(1, 'i');
156af1dcab2Sdan  INSERT INTO main.t1 VALUES(2, 'ii');
157af1dcab2Sdan  INSERT INTO main.t1 VALUES(3, 'iii');
158af1dcab2Sdan} {}
159af1dcab2Sdando_update_tests e_update-1.3 {
160af1dcab2Sdan  1  "UPDATE t1 SET b = 'roman' WHERE a<2 ; SELECT * FROM t1"
161af1dcab2Sdan     {{} {}  1 roman  2 ii  3 iii}
162af1dcab2Sdan
163af1dcab2Sdan  2  "UPDATE t1 SET b = 'egyptian' WHERE (a-3)/10.0 ; SELECT * FROM t1"
164af1dcab2Sdan     {{} {}  1 egyptian  2 egyptian  3 iii}
165af1dcab2Sdan
166af1dcab2Sdan  3  "UPDATE t1 SET b = 'macedonian' WHERE a; SELECT * FROM t1"
167af1dcab2Sdan     {{} {}  1 macedonian  2 macedonian  3 macedonian}
168af1dcab2Sdan
169af1dcab2Sdan  4  "UPDATE t1 SET b = 'lithuanian' WHERE a IS NULL; SELECT * FROM t1"
170af1dcab2Sdan     {{} lithuanian  1 macedonian  2 macedonian  3 macedonian}
171af1dcab2Sdan}
172af1dcab2Sdan
173cc9352e9Sdan# EVIDENCE-OF: R-58129-20729 It is not an error if the WHERE clause does
174cc9352e9Sdan# not evaluate to true for any row in the table - this just means that
175cc9352e9Sdan# the UPDATE statement affects zero rows.
176af1dcab2Sdan#
177af1dcab2Sdando_execsql_test e_update-1.4.0 {
178af1dcab2Sdan  DELETE FROM main.t1;
179af1dcab2Sdan  INSERT INTO main.t1 VALUES(NULL, '');
180af1dcab2Sdan  INSERT INTO main.t1 VALUES(1, 'i');
181af1dcab2Sdan  INSERT INTO main.t1 VALUES(2, 'ii');
182af1dcab2Sdan  INSERT INTO main.t1 VALUES(3, 'iii');
183af1dcab2Sdan} {}
184af1dcab2Sdando_update_tests e_update-1.4 -query {
185af1dcab2Sdan  SELECT * FROM t1
186af1dcab2Sdan} {
187af1dcab2Sdan  1  "UPDATE t1 SET b = 'burmese' WHERE a=5" {{} {}  1 i  2 ii  3 iii}
188af1dcab2Sdan
189af1dcab2Sdan  2  "UPDATE t1 SET b = 'burmese' WHERE length(b)<1 AND a IS NOT NULL"
190af1dcab2Sdan     {{} {}  1 i  2 ii  3 iii}
191af1dcab2Sdan
192af1dcab2Sdan  3  "UPDATE t1 SET b = 'burmese' WHERE 0" {{} {}  1 i  2 ii  3 iii}
193af1dcab2Sdan
194af1dcab2Sdan  4  "UPDATE t1 SET b = 'burmese' WHERE (SELECT a FROM t1 WHERE rowid=1)"
195af1dcab2Sdan     {{} {}  1 i  2 ii  3 iii}
196af1dcab2Sdan}
197af1dcab2Sdan
198af1dcab2Sdan# EVIDENCE-OF: R-40598-36595 For each affected row, the named columns
199af1dcab2Sdan# are set to the values found by evaluating the corresponding scalar
200af1dcab2Sdan# expressions.
201af1dcab2Sdan#
202af1dcab2Sdan# EVIDENCE-OF: R-40472-60438 Columns that do not appear in the list of
203af1dcab2Sdan# assignments are left unmodified.
204af1dcab2Sdan#
205b04757adSdando_execsql_test e_update-1.5.0 {
206af1dcab2Sdan  INSERT INTO t2(rowid, a, b, c) VALUES(1,  3, 1, 4);
207af1dcab2Sdan  INSERT INTO t2(rowid, a, b, c) VALUES(2,  1, 5, 9);
208af1dcab2Sdan  INSERT INTO t2(rowid, a, b, c) VALUES(3,  2, 6, 5);
209af1dcab2Sdan} {}
210b04757adSdando_update_tests e_update-1.5 -query {
211af1dcab2Sdan  SELECT * FROM t2
212af1dcab2Sdan} {
213af1dcab2Sdan  1   "UPDATE t2 SET c = 1+1 WHERE a=2"
214af1dcab2Sdan      {3 1 4   1 5 9   2 6 2}
215af1dcab2Sdan
216af1dcab2Sdan  2   "UPDATE t2 SET b = 4/2, c=CAST((0.4*5) AS INTEGER) WHERE a<3"
217af1dcab2Sdan      {3 1 4   1 2 2   2 2 2}
218af1dcab2Sdan
219af1dcab2Sdan  3   "UPDATE t2 SET a = 1"
220af1dcab2Sdan      {1 1 4   1 2 2   1 2 2}
221af1dcab2Sdan
222af1dcab2Sdan  4   "UPDATE t2 SET b = (SELECT count(*)+2 FROM t2), c = 24/3+1 WHERE rowid=2"
223af1dcab2Sdan      {1 1 4   1 5 9   1 2 2}
224af1dcab2Sdan
225af1dcab2Sdan  5   "UPDATE t2 SET a = 3 WHERE c = 4"
226af1dcab2Sdan      {3 1 4   1 5 9   1 2 2}
227af1dcab2Sdan
228af1dcab2Sdan  6   "UPDATE t2 SET a = b WHERE rowid>2"
229af1dcab2Sdan      {3 1 4   1 5 9   2 2 2}
230af1dcab2Sdan
231af1dcab2Sdan  6   "UPDATE t2 SET b=6, c=5 WHERE a=b AND b=c"
232af1dcab2Sdan      {3 1 4   1 5 9   2 6 5}
233af1dcab2Sdan}
234af1dcab2Sdan
2353c22c604Sdrh# EVIDENCE-OF: R-34751-18293 If a single column-name appears more than
236af1dcab2Sdan# once in the list of assignment expressions, all but the rightmost
2373c22c604Sdrh# occurrence is ignored.
238af1dcab2Sdan#
239b04757adSdando_update_tests e_update-1.6 -query {
240af1dcab2Sdan  SELECT * FROM t2
241af1dcab2Sdan} {
242af1dcab2Sdan  1   "UPDATE t2 SET c=5, c=6, c=7 WHERE rowid=1" {3 1 7   1 5 9   2 6 5}
243af1dcab2Sdan  2   "UPDATE t2 SET c=7, c=6, c=5 WHERE rowid=1" {3 1 5   1 5 9   2 6 5}
244af1dcab2Sdan  3   "UPDATE t2 SET c=5, b=6, c=7 WHERE rowid=1" {3 6 7   1 5 9   2 6 5}
245af1dcab2Sdan}
246af1dcab2Sdan
247af1dcab2Sdan# EVIDENCE-OF: R-36239-04077 The scalar expressions may refer to columns
248af1dcab2Sdan# of the row being updated.
249af1dcab2Sdan#
250af1dcab2Sdan# EVIDENCE-OF: R-04558-24451 In this case all scalar expressions are
251af1dcab2Sdan# evaluated before any assignments are made.
252af1dcab2Sdan#
253b04757adSdando_execsql_test e_update-1.7.0 {
254af1dcab2Sdan  DELETE FROM t2;
255af1dcab2Sdan  INSERT INTO t2(rowid, a, b, c) VALUES(1,  3, 1, 4);
256af1dcab2Sdan  INSERT INTO t2(rowid, a, b, c) VALUES(2,  1, 5, 9);
257af1dcab2Sdan  INSERT INTO t2(rowid, a, b, c) VALUES(3,  2, 6, 5);
258af1dcab2Sdan} {}
259b04757adSdando_update_tests e_update-1.7 -query {
260af1dcab2Sdan  SELECT * FROM t2
261af1dcab2Sdan} {
262af1dcab2Sdan  1   "UPDATE t2 SET a=b+c"          {5 1 4     14 5 9   11  6 5}
263af1dcab2Sdan  2   "UPDATE t2 SET a=b, b=a"       {1 5 4     5 14 9    6 11 5}
264af1dcab2Sdan  3   "UPDATE t2 SET a=c||c, c=NULL" {44 5 {}  99 14 {}  55 11 {}}
265af1dcab2Sdan}
266af1dcab2Sdan
267*b3366b99Sdrh# EVIDENCE-OF: R-28518-13457 The optional "OR action" conflict clause
268*b3366b99Sdrh# that follows the UPDATE keyword allows the user to nominate a specific
269*b3366b99Sdrh# constraint conflict resolution algorithm to use during this one UPDATE
270*b3366b99Sdrh# command.
271af1dcab2Sdan#
272b04757adSdando_execsql_test e_update-1.8.0 {
273af1dcab2Sdan  DELETE FROM t3;
274af1dcab2Sdan  INSERT INTO t3 VALUES(1, 'one');
275af1dcab2Sdan  INSERT INTO t3 VALUES(2, 'two');
276af1dcab2Sdan  INSERT INTO t3 VALUES(3, 'three');
277af1dcab2Sdan  INSERT INTO t3 VALUES(4, 'four');
278af1dcab2Sdan} {}
279af1dcab2Sdanforeach {tn sql error ac data } {
280af1dcab2Sdan  1  "UPDATE t3 SET b='one' WHERE a=3"
281f9c8ce3cSdrh     {UNIQUE constraint failed: t3.b} 1 {1 one 2 two 3 three 4 four}
282af1dcab2Sdan
283af1dcab2Sdan  2  "UPDATE OR REPLACE t3 SET b='one' WHERE a=3"
284af1dcab2Sdan     {} 1 {2 two 3 one 4 four}
285af1dcab2Sdan
286af1dcab2Sdan  3  "UPDATE OR FAIL t3 SET b='three'"
287f9c8ce3cSdrh     {UNIQUE constraint failed: t3.b} 1 {2 three 3 one 4 four}
288af1dcab2Sdan
289af1dcab2Sdan  4  "UPDATE OR IGNORE t3 SET b='three' WHERE a=3"
290af1dcab2Sdan     {} 1 {2 three 3 one 4 four}
291af1dcab2Sdan
292af1dcab2Sdan  5  "UPDATE OR ABORT t3 SET b='three' WHERE a=3"
293f9c8ce3cSdrh     {UNIQUE constraint failed: t3.b} 1 {2 three 3 one 4 four}
294af1dcab2Sdan
295af1dcab2Sdan  6  "BEGIN" {} 0 {2 three 3 one 4 four}
296af1dcab2Sdan
297af1dcab2Sdan  7  "UPDATE t3 SET b='three' WHERE a=3"
298f9c8ce3cSdrh     {UNIQUE constraint failed: t3.b} 0 {2 three 3 one 4 four}
299af1dcab2Sdan
300af1dcab2Sdan  8  "UPDATE OR ABORT t3 SET b='three' WHERE a=3"
301f9c8ce3cSdrh     {UNIQUE constraint failed: t3.b} 0 {2 three 3 one 4 four}
302af1dcab2Sdan
303af1dcab2Sdan  9  "UPDATE OR FAIL t3 SET b='two'"
304f9c8ce3cSdrh     {UNIQUE constraint failed: t3.b} 0 {2 two 3 one 4 four}
305af1dcab2Sdan
306af1dcab2Sdan  10 "UPDATE OR IGNORE t3 SET b='four' WHERE a=3"
307af1dcab2Sdan     {} 0 {2 two 3 one 4 four}
308af1dcab2Sdan
309af1dcab2Sdan  11 "UPDATE OR REPLACE t3 SET b='four' WHERE a=3"
310af1dcab2Sdan     {} 0 {2 two 3 four}
311af1dcab2Sdan
312af1dcab2Sdan  12 "UPDATE OR ROLLBACK t3 SET b='four'"
313f9c8ce3cSdrh     {UNIQUE constraint failed: t3.b} 1 {2 three 3 one 4 four}
314af1dcab2Sdan} {
315b04757adSdan  do_catchsql_test e_update-1.8.$tn.1 $sql [list [expr {$error!=""}] $error]
316b04757adSdan  do_execsql_test  e_update-1.8.$tn.2 {SELECT * FROM t3} [list {*}$data]
317b04757adSdan  do_test          e_update-1.8.$tn.3 {sqlite3_get_autocommit db} $ac
318af1dcab2Sdan}
319af1dcab2Sdan
320b04757adSdan
321b04757adSdan
322b04757adSdan# EVIDENCE-OF: R-12123-54095 The table-name specified as part of an
323b04757adSdan# UPDATE statement within a trigger body must be unqualified.
324b04757adSdan#
325*b3366b99Sdrh# EVIDENCE-OF: R-43190-62442 In other words, the schema-name. prefix on
326*b3366b99Sdrh# the table name of the UPDATE is not allowed within triggers.
327b04757adSdan#
328b04757adSdando_update_tests e_update-2.1 -error {
329b04757adSdan  qualified table names are not allowed on INSERT, UPDATE, and DELETE statements within triggers
330b04757adSdan} {
331b04757adSdan  1 {
332b04757adSdan      CREATE TRIGGER tr1 AFTER INSERT ON t1 BEGIN
333b04757adSdan        UPDATE main.t2 SET a=1, b=2, c=3;
334b04757adSdan      END;
335b04757adSdan  } {}
336b04757adSdan
337b04757adSdan  2 {
338b04757adSdan      CREATE TRIGGER tr1 BEFORE UPDATE ON t2 BEGIN
339b04757adSdan        UPDATE aux.t1 SET a=1, b=2;
340b04757adSdan      END;
341b04757adSdan  } {}
342b04757adSdan
343b04757adSdan  3 {
344b04757adSdan      CREATE TRIGGER tr1 AFTER DELETE ON t4 BEGIN
345b04757adSdan        UPDATE main.t1 SET a=1, b=2;
346b04757adSdan      END;
347b04757adSdan  } {}
348b04757adSdan}
349b04757adSdan
350b04757adSdan# EVIDENCE-OF: R-06085-13761 Unless the table to which the trigger is
351b04757adSdan# attached is in the TEMP database, the table being updated by the
352b04757adSdan# trigger program must reside in the same database as it.
353b04757adSdan#
354b04757adSdando_update_tests e_update-2.2 -error {
355b04757adSdan  no such table: %s
356b04757adSdan} {
357b04757adSdan  1 {
358b04757adSdan      CREATE TRIGGER tr1 AFTER INSERT ON t1 BEGIN
359b04757adSdan        UPDATE t4 SET x=x+1;
360b04757adSdan      END;
361b04757adSdan      INSERT INTO t1 VALUES(1, 2);
362b04757adSdan  } "main.t4"
363b04757adSdan
364b04757adSdan  2 {
365b04757adSdan      CREATE TRIGGER aux.tr1 AFTER INSERT ON t5 BEGIN
366b04757adSdan        UPDATE t4 SET x=x+1;
367b04757adSdan      END;
368b04757adSdan      INSERT INTO t5 VALUES(1, 2);
369b04757adSdan  } "aux.t4"
370b04757adSdan}
371b04757adSdando_execsql_test e_update-2.2.X {
372b04757adSdan  DROP TRIGGER tr1;
373b04757adSdan  DROP TRIGGER aux.tr1;
374b04757adSdan} {}
375b04757adSdan
376b04757adSdan# EVIDENCE-OF: R-29512-54644 If the table to which the trigger is
377b04757adSdan# attached is in the TEMP database, then the unqualified name of the
378b04757adSdan# table being updated is resolved in the same way as it is for a
379b04757adSdan# top-level statement (by searching first the TEMP database, then the
380b04757adSdan# main database, then any other databases in the order they were
381b04757adSdan# attached).
382b04757adSdan#
383b04757adSdando_execsql_test e_update-2.3.0 {
3842f56da3fSdan  SELECT 'main', tbl_name FROM main.sqlite_master WHERE type = 'table';
3852f56da3fSdan  SELECT 'temp', tbl_name FROM sqlite_temp_master WHERE type = 'table';
3862f56da3fSdan  SELECT 'aux', tbl_name FROM aux.sqlite_master WHERE type = 'table';
387b04757adSdan} [list {*}{
388b04757adSdan    main t1
389b04757adSdan    main t2
390b04757adSdan    main t3
391b04757adSdan    main t6
392b04757adSdan    temp t4
393b04757adSdan    temp t6
394b04757adSdan    aux  t1
395b04757adSdan    aux  t5
396b04757adSdan}]
397b04757adSdando_execsql_test e_update-2.3.1 {
398b04757adSdan  DELETE FROM main.t6;
399b04757adSdan  DELETE FROM temp.t6;
400b04757adSdan  INSERT INTO main.t6 VALUES(1, 2);
401b04757adSdan  INSERT INTO temp.t6 VALUES(1, 2);
402b04757adSdan
403b04757adSdan  CREATE TRIGGER temp.tr1 AFTER INSERT ON t4 BEGIN
404b04757adSdan    UPDATE t6 SET x=x+1;
405b04757adSdan  END;
406b04757adSdan
407b04757adSdan  INSERT INTO t4 VALUES(1, 2);
408b04757adSdan  SELECT * FROM main.t6;
409b04757adSdan  SELECT * FROM temp.t6;
410b04757adSdan} {1 2 2 2}
411b04757adSdando_execsql_test e_update-2.3.2 {
412b04757adSdan  DELETE FROM main.t1;
413b04757adSdan  DELETE FROM aux.t1;
414b04757adSdan  INSERT INTO main.t1 VALUES(1, 2);
415b04757adSdan  INSERT INTO aux.t1 VALUES(1, 2);
416b04757adSdan
417b04757adSdan  CREATE TRIGGER temp.tr2 AFTER DELETE ON t4 BEGIN
418b04757adSdan    UPDATE t1 SET a=a+1;
419b04757adSdan  END;
420b04757adSdan
421b04757adSdan  DELETE FROM t4;
422b04757adSdan  SELECT * FROM main.t1;
423b04757adSdan  SELECT * FROM aux.t1;
424b04757adSdan} {2 2 1 2}
425b04757adSdando_execsql_test e_update-2.3.3 {
426b04757adSdan  DELETE FROM aux.t5;
427b04757adSdan  INSERT INTO aux.t5 VALUES(1, 2);
428b04757adSdan
429b04757adSdan  INSERT INTO t4 VALUES('x', 'y');
430b04757adSdan  CREATE TRIGGER temp.tr3 AFTER UPDATE ON t4 BEGIN
431b04757adSdan    UPDATE t5 SET a=a+1;
432b04757adSdan  END;
433b04757adSdan
434b04757adSdan  UPDATE t4 SET x=10;
435b04757adSdan  SELECT * FROM aux.t5;
436b04757adSdan} {2 2}
437b04757adSdan
438b04757adSdan# EVIDENCE-OF: R-19619-42762 The INDEXED BY and NOT INDEXED clauses are
439b04757adSdan# not allowed on UPDATE statements within triggers.
440b04757adSdan#
441b04757adSdando_update_tests e_update-2.4 -error {
442b04757adSdan  the %s %s clause is not allowed on UPDATE or DELETE statements within triggers
443b04757adSdan} {
444b04757adSdan  1 {
445b04757adSdan      CREATE TRIGGER tr1 AFTER INSERT ON t2 BEGIN
446b04757adSdan        UPDATE t1 INDEXED BY i1 SET a=a+1;
447b04757adSdan      END;
448b04757adSdan  } {INDEXED BY}
449b04757adSdan
450b04757adSdan  2 {
451b04757adSdan      CREATE TRIGGER tr1 AFTER INSERT ON t2 BEGIN
452b04757adSdan        UPDATE t1 NOT INDEXED SET a=a+1;
453b04757adSdan      END;
454b04757adSdan  } {NOT INDEXED}
455b04757adSdan}
456b04757adSdan
457b04757adSdanifcapable update_delete_limit {
458b04757adSdan
459b04757adSdan# EVIDENCE-OF: R-57359-59558 The LIMIT and ORDER BY clauses for UPDATE
460b04757adSdan# are unsupported within triggers, regardless of the compilation options
461b04757adSdan# used to build SQLite.
462b04757adSdan#
463b04757adSdando_update_tests e_update-2.5 -error {
464b04757adSdan  near "%s": syntax error
465b04757adSdan} {
466b04757adSdan  1 {
467b04757adSdan      CREATE TRIGGER tr1 AFTER INSERT ON t2 BEGIN
468b04757adSdan        UPDATE t1 SET a=a+1 LIMIT 10;
469b04757adSdan      END;
470b04757adSdan  } {LIMIT}
471b04757adSdan
472b04757adSdan  2 {
473b04757adSdan      CREATE TRIGGER tr1 AFTER INSERT ON t2 BEGIN
474b04757adSdan        UPDATE t1 SET a=a+1 ORDER BY a LIMIT 10;
475b04757adSdan      END;
476b04757adSdan  } {ORDER}
477b04757adSdan
478b04757adSdan  3 {
479b04757adSdan      CREATE TRIGGER tr1 AFTER INSERT ON t2 BEGIN
480b04757adSdan        UPDATE t1 SET a=a+1 ORDER BY a LIMIT 10 OFFSET 2;
481b04757adSdan      END;
482b04757adSdan  } {ORDER}
483b04757adSdan
484b04757adSdan  4 {
485b04757adSdan      CREATE TRIGGER tr1 AFTER INSERT ON t2 BEGIN
486b04757adSdan        UPDATE t1 SET a=a+1 LIMIT 10 OFFSET 2;
487b04757adSdan      END;
488b04757adSdan  } {LIMIT}
489b04757adSdan}
490b04757adSdan
491b04757adSdan# EVIDENCE-OF: R-59581-44104 If SQLite is built with the
492b04757adSdan# SQLITE_ENABLE_UPDATE_DELETE_LIMIT compile-time option then the syntax
493b04757adSdan# of the UPDATE statement is extended with optional ORDER BY and LIMIT
494b04757adSdan# clauses
495b04757adSdan#
49639759747Sdrh# -- syntax diagram update-stmt-limited
497b04757adSdan#
498b04757adSdando_update_tests e_update-3.0 {
499b04757adSdan  1   "UPDATE t1 SET a=b LIMIT 5"                                    {}
500b04757adSdan  2   "UPDATE t1 SET a=b LIMIT 5-1 OFFSET 2+2"                       {}
501b04757adSdan  3   "UPDATE t1 SET a=b LIMIT 2+2, 16/4"                            {}
502b04757adSdan  4   "UPDATE t1 SET a=b ORDER BY a LIMIT 5"                         {}
503b04757adSdan  5   "UPDATE t1 SET a=b ORDER BY a LIMIT 5-1 OFFSET 2+2"            {}
504b04757adSdan  6   "UPDATE t1 SET a=b ORDER BY a LIMIT 2+2, 16/4"                 {}
505b04757adSdan  7   "UPDATE t1 SET a=b WHERE a>2 LIMIT 5"                          {}
506b04757adSdan  8   "UPDATE t1 SET a=b WHERE a>2 LIMIT 5-1 OFFSET 2+2"             {}
507b04757adSdan  9   "UPDATE t1 SET a=b WHERE a>2 LIMIT 2+2, 16/4"                  {}
508b04757adSdan  10  "UPDATE t1 SET a=b WHERE a>2 ORDER BY a LIMIT 5"               {}
509b04757adSdan  11  "UPDATE t1 SET a=b WHERE a>2 ORDER BY a LIMIT 5-1 OFFSET 2+2"  {}
510b04757adSdan  12  "UPDATE t1 SET a=b WHERE a>2 ORDER BY a LIMIT 2+2, 16/4"       {}
511b04757adSdan}
512b04757adSdan
513b04757adSdando_execsql_test e_update-3.1.0 {
514b04757adSdan  CREATE TABLE t7(q, r, s);
515b04757adSdan  INSERT INTO t7 VALUES(1, 'one',   'X');
516b04757adSdan  INSERT INTO t7 VALUES(2, 'two',   'X');
517b04757adSdan  INSERT INTO t7 VALUES(3, 'three', 'X');
518b04757adSdan  INSERT INTO t7 VALUES(4, 'four',  'X');
519b04757adSdan  INSERT INTO t7 VALUES(5, 'five',  'X');
520b04757adSdan  INSERT INTO t7 VALUES(6, 'six',   'X');
521b04757adSdan  INSERT INTO t7 VALUES(7, 'seven', 'X');
522b04757adSdan  INSERT INTO t7 VALUES(8, 'eight', 'X');
523b04757adSdan  INSERT INTO t7 VALUES(9, 'nine',  'X');
524b04757adSdan  INSERT INTO t7 VALUES(10, 'ten',  'X');
525b04757adSdan} {}
526b04757adSdan
527b04757adSdan# EVIDENCE-OF: R-58862-44169 If an UPDATE statement has a LIMIT clause,
528b04757adSdan# the maximum number of rows that will be updated is found by evaluating
529b04757adSdan# the accompanying expression and casting it to an integer value.
530b04757adSdan#
531b04757adSdando_update_tests e_update-3.1 -query { SELECT s FROM t7 } {
532b04757adSdan  1   "UPDATE t7 SET s = q LIMIT 5"            {1 2 3 4 5 X X X X X}
533b04757adSdan  2   "UPDATE t7 SET s = r WHERE q>2 LIMIT 4"  {1 2 three four five six X X X X}
534b04757adSdan  3   "UPDATE t7 SET s = q LIMIT 0"            {1 2 three four five six X X X X}
535b04757adSdan}
536b04757adSdan
537b04757adSdan# EVIDENCE-OF: R-63582-45120 A negative value is interpreted as "no limit".
538b04757adSdan#
539b04757adSdando_update_tests e_update-3.2 -query { SELECT s FROM t7 } {
540b04757adSdan  1   "UPDATE t7 SET s = q LIMIT -1"              {1 2 3 4 5 6 7 8 9 10}
541b04757adSdan  2   "UPDATE t7 SET s = r WHERE q>4 LIMIT -1"
542b04757adSdan      {1 2 3 4 five six seven eight nine ten}
543b04757adSdan  3   "UPDATE t7 SET s = 'X' LIMIT -1"            {X X X X X X X X X X}
544b04757adSdan}
545b04757adSdan
546b04757adSdan# EVIDENCE-OF: R-18628-11938 If the LIMIT expression evaluates to
547b04757adSdan# non-negative value N and the UPDATE statement has an ORDER BY clause,
548b04757adSdan# then all rows that would be updated in the absence of the LIMIT clause
549b04757adSdan# are sorted according to the ORDER BY and the first N updated.
550b04757adSdan#
551b04757adSdando_update_tests e_update-3.3 -query { SELECT s FROM t7 } {
552b04757adSdan  1   "UPDATE t7 SET s = q ORDER BY r LIMIT 3"      {X X X 4 5 X X 8 X X}
553b04757adSdan  2   "UPDATE t7 SET s = r ORDER BY r DESC LIMIT 2" {X two three 4 5 X X 8 X X}
554b04757adSdan  3   "UPDATE t7 SET s = q ORDER BY q DESC LIMIT 5" {X two three 4 5 6 7 8 9 10}
555b04757adSdan
556b04757adSdan  X   "UPDATE t7 SET s = 'X'"                       {X X X X X X X X X X}
557b04757adSdan}
558b04757adSdan
559b04757adSdan# EVIDENCE-OF: R-30955-38324 If the UPDATE statement also has an OFFSET
560b04757adSdan# clause, then it is similarly evaluated and cast to an integer value.
561b04757adSdan# If the OFFSET expression evaluates to a non-negative value M, then the
562b04757adSdan# first M rows are skipped and the following N rows updated instead.
563b04757adSdan#
564b04757adSdando_update_tests e_update-3.3 -query { SELECT s FROM t7 } {
565b04757adSdan  1   "UPDATE t7 SET s = q ORDER BY q LIMIT 3 OFFSET 2"  {X X 3 4 5 X X X X X}
566b04757adSdan  2   "UPDATE t7 SET s = q ORDER BY q DESC LIMIT 2, 3 "  {X X 3 4 5 6 7 8 X X}
567b04757adSdan
568b04757adSdan  X   "UPDATE t7 SET s = 'X'"                       {X X X X X X X X X X}
569b04757adSdan}
570b04757adSdan
571b04757adSdan# EVIDENCE-OF: R-19486-35828 If the UPDATE statement has no ORDER BY
572b04757adSdan# clause, then all rows that would be updated in the absence of the
573b04757adSdan# LIMIT clause are assembled in an arbitrary order before applying the
574b04757adSdan# LIMIT and OFFSET clauses to determine which are actually updated.
575b04757adSdan#
576b04757adSdan#     In practice, "arbitrary order" is rowid order. This is also tested
577b04757adSdan#     by e_update-3.2.* above.
578b04757adSdan#
579b04757adSdando_update_tests e_update-3.4 -query { SELECT s FROM t7 } {
580b04757adSdan  1   "UPDATE t7 SET s = q LIMIT 4, 2"        {X X X X 5 6 X X X X}
581b04757adSdan  2   "UPDATE t7 SET s = q LIMIT 2 OFFSET 7"  {X X X X 5 6 X 8 9 X}
582b04757adSdan}
583b04757adSdan
584b04757adSdan# EVIDENCE-OF: R-10927-26133 The ORDER BY clause on an UPDATE statement
585b04757adSdan# is used only to determine which rows fall within the LIMIT. The order
586b04757adSdan# in which rows are modified is arbitrary and is not influenced by the
587b04757adSdan# ORDER BY clause.
588b04757adSdan#
589b04757adSdando_execsql_test e_update-3.5.0 {
590b04757adSdan  CREATE TABLE t8(x);
591b04757adSdan  CREATE TRIGGER tr7 BEFORE UPDATE ON t7 BEGIN
592b04757adSdan    INSERT INTO t8 VALUES(old.q);
593b04757adSdan  END;
594b04757adSdan} {}
595b04757adSdando_update_tests e_update-3.5 -query { SELECT x FROM t8 ; DELETE FROM t8 } {
596b04757adSdan  1   "UPDATE t7 SET s = q ORDER BY r LIMIT -1"        {1 2 3 4 5 6 7 8 9 10}
597b04757adSdan  2   "UPDATE t7 SET s = q ORDER BY r ASC LIMIT -1"    {1 2 3 4 5 6 7 8 9 10}
598b04757adSdan  3   "UPDATE t7 SET s = q ORDER BY r DESC LIMIT -1"   {1 2 3 4 5 6 7 8 9 10}
599b04757adSdan  4   "UPDATE t7 SET s = q ORDER BY q DESC LIMIT 5"    {6 7 8 9 10}
600b04757adSdan}
601b04757adSdan
602b04757adSdan
603b04757adSdan} ;# ifcapable update_delete_limit
604b04757adSdan
605af1dcab2Sdanfinish_test
606