sqlite/test/e_update.test
drh f9c8ce3ced Standardize the error messages generated by constraint failures to a format
of "$TYPE constraint failed: $DETAIL".  This involves many changes to the
expected output of test cases.

FossilOrigin-Name: 54b221929744b1bcdbcc2030fef2e510618afd41
2013-11-05 13:33:55 +00:00

606 lines
20 KiB
Plaintext

# 2010 September 20
#
# The author disclaims copyright to this source code. In place of
# a legal notice, here is a blessing:
#
# May you do good and not evil.
# May you find forgiveness for yourself and forgive others.
# May you share freely, never taking more than you give.
#
#***********************************************************************
#
# This file implements tests to verify that the "testable statements" in
# the lang_update.html document are correct.
#
set testdir [file dirname $argv0]
source $testdir/tester.tcl
#--------------------
# Test organization:
#
# e_update-1.*: Test statements describing the workings of UPDATE statements.
#
# e_update-2.*: Test the restrictions on the UPDATE statement syntax that
# can be used within triggers.
#
# e_update-3.*: Test the special LIMIT/OFFSET and ORDER BY clauses that can
# be used with UPDATE when SQLite is compiled with
# SQLITE_ENABLE_UPDATE_DELETE_LIMIT.
#
forcedelete test.db2
do_execsql_test e_update-0.0 {
ATTACH 'test.db2' AS aux;
CREATE TABLE t1(a, b);
CREATE TABLE t2(a, b, c);
CREATE TABLE t3(a, b UNIQUE);
CREATE TABLE t6(x, y);
CREATE INDEX i1 ON t1(a);
CREATE TEMP TABLE t4(x, y);
CREATE TEMP TABLE t6(x, y);
CREATE TABLE aux.t1(a, b);
CREATE TABLE aux.t5(a, b);
} {}
proc do_update_tests {args} {
uplevel do_select_tests $args
}
# -- syntax diagram update-stmt
#
do_update_tests e_update-0 {
1 "UPDATE t1 SET a=10" {}
2 "UPDATE t1 SET a=10, b=5" {}
3 "UPDATE t1 SET a=10 WHERE b=5" {}
4 "UPDATE t1 SET b=5,a=10 WHERE 1" {}
5 "UPDATE main.t1 SET a=10" {}
6 "UPDATE main.t1 SET a=10, b=5" {}
7 "UPDATE main.t1 SET a=10 WHERE b=5" {}
9 "UPDATE OR ROLLBACK t1 SET a=10" {}
10 "UPDATE OR ROLLBACK t1 SET a=10, b=5" {}
11 "UPDATE OR ROLLBACK t1 SET a=10 WHERE b=5" {}
12 "UPDATE OR ROLLBACK t1 SET b=5,a=10 WHERE 1" {}
13 "UPDATE OR ROLLBACK main.t1 SET a=10" {}
14 "UPDATE OR ROLLBACK main.t1 SET a=10, b=5" {}
15 "UPDATE OR ROLLBACK main.t1 SET a=10 WHERE b=5" {}
16 "UPDATE OR ROLLBACK main.t1 SET b=5,a=10 WHERE 1" {}
17 "UPDATE OR ABORT t1 SET a=10" {}
18 "UPDATE OR ABORT t1 SET a=10, b=5" {}
19 "UPDATE OR ABORT t1 SET a=10 WHERE b=5" {}
20 "UPDATE OR ABORT t1 SET b=5,a=10 WHERE 1" {}
21 "UPDATE OR ABORT main.t1 SET a=10" {}
22 "UPDATE OR ABORT main.t1 SET a=10, b=5" {}
23 "UPDATE OR ABORT main.t1 SET a=10 WHERE b=5" {}
24 "UPDATE OR ABORT main.t1 SET b=5,a=10 WHERE 1" {}
25 "UPDATE OR REPLACE t1 SET a=10" {}
26 "UPDATE OR REPLACE t1 SET a=10, b=5" {}
27 "UPDATE OR REPLACE t1 SET a=10 WHERE b=5" {}
28 "UPDATE OR REPLACE t1 SET b=5,a=10 WHERE 1" {}
29 "UPDATE OR REPLACE main.t1 SET a=10" {}
30 "UPDATE OR REPLACE main.t1 SET a=10, b=5" {}
31 "UPDATE OR REPLACE main.t1 SET a=10 WHERE b=5" {}
32 "UPDATE OR REPLACE main.t1 SET b=5,a=10 WHERE 1" {}
33 "UPDATE OR FAIL t1 SET a=10" {}
34 "UPDATE OR FAIL t1 SET a=10, b=5" {}
35 "UPDATE OR FAIL t1 SET a=10 WHERE b=5" {}
36 "UPDATE OR FAIL t1 SET b=5,a=10 WHERE 1" {}
37 "UPDATE OR FAIL main.t1 SET a=10" {}
38 "UPDATE OR FAIL main.t1 SET a=10, b=5" {}
39 "UPDATE OR FAIL main.t1 SET a=10 WHERE b=5" {}
40 "UPDATE OR FAIL main.t1 SET b=5,a=10 WHERE 1" {}
41 "UPDATE OR IGNORE t1 SET a=10" {}
42 "UPDATE OR IGNORE t1 SET a=10, b=5" {}
43 "UPDATE OR IGNORE t1 SET a=10 WHERE b=5" {}
44 "UPDATE OR IGNORE t1 SET b=5,a=10 WHERE 1" {}
45 "UPDATE OR IGNORE main.t1 SET a=10" {}
46 "UPDATE OR IGNORE main.t1 SET a=10, b=5" {}
47 "UPDATE OR IGNORE main.t1 SET a=10 WHERE b=5" {}
48 "UPDATE OR IGNORE main.t1 SET b=5,a=10 WHERE 1" {}
}
# EVIDENCE-OF: R-38515-45264 An UPDATE statement is used to modify a
# subset of the values stored in zero or more rows of the database table
# identified by the qualified-table-name specified as part of the UPDATE
# statement.
#
# Test cases e_update-1.1.1.* test the "identified by the
# qualified-table-name" part of the statement above. Tests
# e_update-1.1.2.* show that the "zero or more rows" part is
# accurate.
#
do_execsql_test e_update-1.1.0 {
INSERT INTO main.t1 VALUES(1, 'i');
INSERT INTO main.t1 VALUES(2, 'ii');
INSERT INTO main.t1 VALUES(3, 'iii');
INSERT INTO aux.t1 VALUES(1, 'I');
INSERT INTO aux.t1 VALUES(2, 'II');
INSERT INTO aux.t1 VALUES(3, 'III');
} {}
do_update_tests e_update-1.1 {
1.1 "UPDATE t1 SET a = a+1; SELECT * FROM t1" {2 i 3 ii 4 iii}
1.2 "UPDATE main.t1 SET a = a+1; SELECT * FROM main.t1" {3 i 4 ii 5 iii}
1.3 "UPDATE aux.t1 SET a = a+1; SELECT * FROM aux.t1" {2 I 3 II 4 III}
2.1 "UPDATE t1 SET a = a+1 WHERE a = 1; SELECT * FROM t1" {3 i 4 ii 5 iii}
2.2 "UPDATE t1 SET a = a+1 WHERE a = 4; SELECT * FROM t1" {3 i 5 ii 5 iii}
}
# EVIDENCE-OF: R-55869-30521 If the UPDATE statement does not have a
# WHERE clause, all rows in the table are modified by the UPDATE.
#
do_execsql_test e_update-1.2.0 {
DELETE FROM main.t1;
INSERT INTO main.t1 VALUES(1, 'i');
INSERT INTO main.t1 VALUES(2, 'ii');
INSERT INTO main.t1 VALUES(3, 'iii');
} {}
do_update_tests e_update-1.2 {
1 "UPDATE t1 SET b = 'roman' ; SELECT * FROM t1"
{1 roman 2 roman 3 roman}
2 "UPDATE t1 SET a = 'greek' ; SELECT * FROM t1"
{greek roman greek roman greek roman}
}
# EVIDENCE-OF: R-42117-40023 Otherwise, the UPDATE affects only those
# rows for which the result of evaluating the WHERE clause expression as
# a boolean expression is true.
#
do_execsql_test e_update-1.3.0 {
DELETE FROM main.t1;
INSERT INTO main.t1 VALUES(NULL, '');
INSERT INTO main.t1 VALUES(1, 'i');
INSERT INTO main.t1 VALUES(2, 'ii');
INSERT INTO main.t1 VALUES(3, 'iii');
} {}
do_update_tests e_update-1.3 {
1 "UPDATE t1 SET b = 'roman' WHERE a<2 ; SELECT * FROM t1"
{{} {} 1 roman 2 ii 3 iii}
2 "UPDATE t1 SET b = 'egyptian' WHERE (a-3)/10.0 ; SELECT * FROM t1"
{{} {} 1 egyptian 2 egyptian 3 iii}
3 "UPDATE t1 SET b = 'macedonian' WHERE a; SELECT * FROM t1"
{{} {} 1 macedonian 2 macedonian 3 macedonian}
4 "UPDATE t1 SET b = 'lithuanian' WHERE a IS NULL; SELECT * FROM t1"
{{} lithuanian 1 macedonian 2 macedonian 3 macedonian}
}
# EVIDENCE-OF: R-58129-20729 It is not an error if the WHERE clause does
# not evaluate to true for any row in the table - this just means that
# the UPDATE statement affects zero rows.
#
do_execsql_test e_update-1.4.0 {
DELETE FROM main.t1;
INSERT INTO main.t1 VALUES(NULL, '');
INSERT INTO main.t1 VALUES(1, 'i');
INSERT INTO main.t1 VALUES(2, 'ii');
INSERT INTO main.t1 VALUES(3, 'iii');
} {}
do_update_tests e_update-1.4 -query {
SELECT * FROM t1
} {
1 "UPDATE t1 SET b = 'burmese' WHERE a=5" {{} {} 1 i 2 ii 3 iii}
2 "UPDATE t1 SET b = 'burmese' WHERE length(b)<1 AND a IS NOT NULL"
{{} {} 1 i 2 ii 3 iii}
3 "UPDATE t1 SET b = 'burmese' WHERE 0" {{} {} 1 i 2 ii 3 iii}
4 "UPDATE t1 SET b = 'burmese' WHERE (SELECT a FROM t1 WHERE rowid=1)"
{{} {} 1 i 2 ii 3 iii}
}
# EVIDENCE-OF: R-40598-36595 For each affected row, the named columns
# are set to the values found by evaluating the corresponding scalar
# expressions.
#
# EVIDENCE-OF: R-40472-60438 Columns that do not appear in the list of
# assignments are left unmodified.
#
do_execsql_test e_update-1.5.0 {
INSERT INTO t2(rowid, a, b, c) VALUES(1, 3, 1, 4);
INSERT INTO t2(rowid, a, b, c) VALUES(2, 1, 5, 9);
INSERT INTO t2(rowid, a, b, c) VALUES(3, 2, 6, 5);
} {}
do_update_tests e_update-1.5 -query {
SELECT * FROM t2
} {
1 "UPDATE t2 SET c = 1+1 WHERE a=2"
{3 1 4 1 5 9 2 6 2}
2 "UPDATE t2 SET b = 4/2, c=CAST((0.4*5) AS INTEGER) WHERE a<3"
{3 1 4 1 2 2 2 2 2}
3 "UPDATE t2 SET a = 1"
{1 1 4 1 2 2 1 2 2}
4 "UPDATE t2 SET b = (SELECT count(*)+2 FROM t2), c = 24/3+1 WHERE rowid=2"
{1 1 4 1 5 9 1 2 2}
5 "UPDATE t2 SET a = 3 WHERE c = 4"
{3 1 4 1 5 9 1 2 2}
6 "UPDATE t2 SET a = b WHERE rowid>2"
{3 1 4 1 5 9 2 2 2}
6 "UPDATE t2 SET b=6, c=5 WHERE a=b AND b=c"
{3 1 4 1 5 9 2 6 5}
}
# EVIDENCE-OF: R-34751-18293 If a single column-name appears more than
# once in the list of assignment expressions, all but the rightmost
# occurrence is ignored.
#
do_update_tests e_update-1.6 -query {
SELECT * FROM t2
} {
1 "UPDATE t2 SET c=5, c=6, c=7 WHERE rowid=1" {3 1 7 1 5 9 2 6 5}
2 "UPDATE t2 SET c=7, c=6, c=5 WHERE rowid=1" {3 1 5 1 5 9 2 6 5}
3 "UPDATE t2 SET c=5, b=6, c=7 WHERE rowid=1" {3 6 7 1 5 9 2 6 5}
}
# EVIDENCE-OF: R-36239-04077 The scalar expressions may refer to columns
# of the row being updated.
#
# EVIDENCE-OF: R-04558-24451 In this case all scalar expressions are
# evaluated before any assignments are made.
#
do_execsql_test e_update-1.7.0 {
DELETE FROM t2;
INSERT INTO t2(rowid, a, b, c) VALUES(1, 3, 1, 4);
INSERT INTO t2(rowid, a, b, c) VALUES(2, 1, 5, 9);
INSERT INTO t2(rowid, a, b, c) VALUES(3, 2, 6, 5);
} {}
do_update_tests e_update-1.7 -query {
SELECT * FROM t2
} {
1 "UPDATE t2 SET a=b+c" {5 1 4 14 5 9 11 6 5}
2 "UPDATE t2 SET a=b, b=a" {1 5 4 5 14 9 6 11 5}
3 "UPDATE t2 SET a=c||c, c=NULL" {44 5 {} 99 14 {} 55 11 {}}
}
# EVIDENCE-OF: R-12619-24112 The optional conflict-clause allows the
# user to nominate a specific constraint conflict resolution algorithm
# to use during this one UPDATE command.
#
do_execsql_test e_update-1.8.0 {
DELETE FROM t3;
INSERT INTO t3 VALUES(1, 'one');
INSERT INTO t3 VALUES(2, 'two');
INSERT INTO t3 VALUES(3, 'three');
INSERT INTO t3 VALUES(4, 'four');
} {}
foreach {tn sql error ac data } {
1 "UPDATE t3 SET b='one' WHERE a=3"
{UNIQUE constraint failed: t3.b} 1 {1 one 2 two 3 three 4 four}
2 "UPDATE OR REPLACE t3 SET b='one' WHERE a=3"
{} 1 {2 two 3 one 4 four}
3 "UPDATE OR FAIL t3 SET b='three'"
{UNIQUE constraint failed: t3.b} 1 {2 three 3 one 4 four}
4 "UPDATE OR IGNORE t3 SET b='three' WHERE a=3"
{} 1 {2 three 3 one 4 four}
5 "UPDATE OR ABORT t3 SET b='three' WHERE a=3"
{UNIQUE constraint failed: t3.b} 1 {2 three 3 one 4 four}
6 "BEGIN" {} 0 {2 three 3 one 4 four}
7 "UPDATE t3 SET b='three' WHERE a=3"
{UNIQUE constraint failed: t3.b} 0 {2 three 3 one 4 four}
8 "UPDATE OR ABORT t3 SET b='three' WHERE a=3"
{UNIQUE constraint failed: t3.b} 0 {2 three 3 one 4 four}
9 "UPDATE OR FAIL t3 SET b='two'"
{UNIQUE constraint failed: t3.b} 0 {2 two 3 one 4 four}
10 "UPDATE OR IGNORE t3 SET b='four' WHERE a=3"
{} 0 {2 two 3 one 4 four}
11 "UPDATE OR REPLACE t3 SET b='four' WHERE a=3"
{} 0 {2 two 3 four}
12 "UPDATE OR ROLLBACK t3 SET b='four'"
{UNIQUE constraint failed: t3.b} 1 {2 three 3 one 4 four}
} {
do_catchsql_test e_update-1.8.$tn.1 $sql [list [expr {$error!=""}] $error]
do_execsql_test e_update-1.8.$tn.2 {SELECT * FROM t3} [list {*}$data]
do_test e_update-1.8.$tn.3 {sqlite3_get_autocommit db} $ac
}
# EVIDENCE-OF: R-12123-54095 The table-name specified as part of an
# UPDATE statement within a trigger body must be unqualified.
#
# EVIDENCE-OF: R-09690-36749 In other words, the database-name. prefix
# on the table name of the UPDATE is not allowed within triggers.
#
do_update_tests e_update-2.1 -error {
qualified table names are not allowed on INSERT, UPDATE, and DELETE statements within triggers
} {
1 {
CREATE TRIGGER tr1 AFTER INSERT ON t1 BEGIN
UPDATE main.t2 SET a=1, b=2, c=3;
END;
} {}
2 {
CREATE TRIGGER tr1 BEFORE UPDATE ON t2 BEGIN
UPDATE aux.t1 SET a=1, b=2;
END;
} {}
3 {
CREATE TRIGGER tr1 AFTER DELETE ON t4 BEGIN
UPDATE main.t1 SET a=1, b=2;
END;
} {}
}
# EVIDENCE-OF: R-06085-13761 Unless the table to which the trigger is
# attached is in the TEMP database, the table being updated by the
# trigger program must reside in the same database as it.
#
do_update_tests e_update-2.2 -error {
no such table: %s
} {
1 {
CREATE TRIGGER tr1 AFTER INSERT ON t1 BEGIN
UPDATE t4 SET x=x+1;
END;
INSERT INTO t1 VALUES(1, 2);
} "main.t4"
2 {
CREATE TRIGGER aux.tr1 AFTER INSERT ON t5 BEGIN
UPDATE t4 SET x=x+1;
END;
INSERT INTO t5 VALUES(1, 2);
} "aux.t4"
}
do_execsql_test e_update-2.2.X {
DROP TRIGGER tr1;
DROP TRIGGER aux.tr1;
} {}
# EVIDENCE-OF: R-29512-54644 If the table to which the trigger is
# attached is in the TEMP database, then the unqualified name of the
# table being updated is resolved in the same way as it is for a
# top-level statement (by searching first the TEMP database, then the
# main database, then any other databases in the order they were
# attached).
#
do_execsql_test e_update-2.3.0 {
SELECT 'main', tbl_name FROM main.sqlite_master WHERE type = 'table';
SELECT 'temp', tbl_name FROM sqlite_temp_master WHERE type = 'table';
SELECT 'aux', tbl_name FROM aux.sqlite_master WHERE type = 'table';
} [list {*}{
main t1
main t2
main t3
main t6
temp t4
temp t6
aux t1
aux t5
}]
do_execsql_test e_update-2.3.1 {
DELETE FROM main.t6;
DELETE FROM temp.t6;
INSERT INTO main.t6 VALUES(1, 2);
INSERT INTO temp.t6 VALUES(1, 2);
CREATE TRIGGER temp.tr1 AFTER INSERT ON t4 BEGIN
UPDATE t6 SET x=x+1;
END;
INSERT INTO t4 VALUES(1, 2);
SELECT * FROM main.t6;
SELECT * FROM temp.t6;
} {1 2 2 2}
do_execsql_test e_update-2.3.2 {
DELETE FROM main.t1;
DELETE FROM aux.t1;
INSERT INTO main.t1 VALUES(1, 2);
INSERT INTO aux.t1 VALUES(1, 2);
CREATE TRIGGER temp.tr2 AFTER DELETE ON t4 BEGIN
UPDATE t1 SET a=a+1;
END;
DELETE FROM t4;
SELECT * FROM main.t1;
SELECT * FROM aux.t1;
} {2 2 1 2}
do_execsql_test e_update-2.3.3 {
DELETE FROM aux.t5;
INSERT INTO aux.t5 VALUES(1, 2);
INSERT INTO t4 VALUES('x', 'y');
CREATE TRIGGER temp.tr3 AFTER UPDATE ON t4 BEGIN
UPDATE t5 SET a=a+1;
END;
UPDATE t4 SET x=10;
SELECT * FROM aux.t5;
} {2 2}
# EVIDENCE-OF: R-19619-42762 The INDEXED BY and NOT INDEXED clauses are
# not allowed on UPDATE statements within triggers.
#
do_update_tests e_update-2.4 -error {
the %s %s clause is not allowed on UPDATE or DELETE statements within triggers
} {
1 {
CREATE TRIGGER tr1 AFTER INSERT ON t2 BEGIN
UPDATE t1 INDEXED BY i1 SET a=a+1;
END;
} {INDEXED BY}
2 {
CREATE TRIGGER tr1 AFTER INSERT ON t2 BEGIN
UPDATE t1 NOT INDEXED SET a=a+1;
END;
} {NOT INDEXED}
}
ifcapable update_delete_limit {
# EVIDENCE-OF: R-57359-59558 The LIMIT and ORDER BY clauses for UPDATE
# are unsupported within triggers, regardless of the compilation options
# used to build SQLite.
#
do_update_tests e_update-2.5 -error {
near "%s": syntax error
} {
1 {
CREATE TRIGGER tr1 AFTER INSERT ON t2 BEGIN
UPDATE t1 SET a=a+1 LIMIT 10;
END;
} {LIMIT}
2 {
CREATE TRIGGER tr1 AFTER INSERT ON t2 BEGIN
UPDATE t1 SET a=a+1 ORDER BY a LIMIT 10;
END;
} {ORDER}
3 {
CREATE TRIGGER tr1 AFTER INSERT ON t2 BEGIN
UPDATE t1 SET a=a+1 ORDER BY a LIMIT 10 OFFSET 2;
END;
} {ORDER}
4 {
CREATE TRIGGER tr1 AFTER INSERT ON t2 BEGIN
UPDATE t1 SET a=a+1 LIMIT 10 OFFSET 2;
END;
} {LIMIT}
}
# EVIDENCE-OF: R-59581-44104 If SQLite is built with the
# SQLITE_ENABLE_UPDATE_DELETE_LIMIT compile-time option then the syntax
# of the UPDATE statement is extended with optional ORDER BY and LIMIT
# clauses
#
# -- syntax diagram update-stmt-limited
#
do_update_tests e_update-3.0 {
1 "UPDATE t1 SET a=b LIMIT 5" {}
2 "UPDATE t1 SET a=b LIMIT 5-1 OFFSET 2+2" {}
3 "UPDATE t1 SET a=b LIMIT 2+2, 16/4" {}
4 "UPDATE t1 SET a=b ORDER BY a LIMIT 5" {}
5 "UPDATE t1 SET a=b ORDER BY a LIMIT 5-1 OFFSET 2+2" {}
6 "UPDATE t1 SET a=b ORDER BY a LIMIT 2+2, 16/4" {}
7 "UPDATE t1 SET a=b WHERE a>2 LIMIT 5" {}
8 "UPDATE t1 SET a=b WHERE a>2 LIMIT 5-1 OFFSET 2+2" {}
9 "UPDATE t1 SET a=b WHERE a>2 LIMIT 2+2, 16/4" {}
10 "UPDATE t1 SET a=b WHERE a>2 ORDER BY a LIMIT 5" {}
11 "UPDATE t1 SET a=b WHERE a>2 ORDER BY a LIMIT 5-1 OFFSET 2+2" {}
12 "UPDATE t1 SET a=b WHERE a>2 ORDER BY a LIMIT 2+2, 16/4" {}
}
do_execsql_test e_update-3.1.0 {
CREATE TABLE t7(q, r, s);
INSERT INTO t7 VALUES(1, 'one', 'X');
INSERT INTO t7 VALUES(2, 'two', 'X');
INSERT INTO t7 VALUES(3, 'three', 'X');
INSERT INTO t7 VALUES(4, 'four', 'X');
INSERT INTO t7 VALUES(5, 'five', 'X');
INSERT INTO t7 VALUES(6, 'six', 'X');
INSERT INTO t7 VALUES(7, 'seven', 'X');
INSERT INTO t7 VALUES(8, 'eight', 'X');
INSERT INTO t7 VALUES(9, 'nine', 'X');
INSERT INTO t7 VALUES(10, 'ten', 'X');
} {}
# EVIDENCE-OF: R-58862-44169 If an UPDATE statement has a LIMIT clause,
# the maximum number of rows that will be updated is found by evaluating
# the accompanying expression and casting it to an integer value.
#
do_update_tests e_update-3.1 -query { SELECT s FROM t7 } {
1 "UPDATE t7 SET s = q LIMIT 5" {1 2 3 4 5 X X X X X}
2 "UPDATE t7 SET s = r WHERE q>2 LIMIT 4" {1 2 three four five six X X X X}
3 "UPDATE t7 SET s = q LIMIT 0" {1 2 three four five six X X X X}
}
# EVIDENCE-OF: R-63582-45120 A negative value is interpreted as "no limit".
#
do_update_tests e_update-3.2 -query { SELECT s FROM t7 } {
1 "UPDATE t7 SET s = q LIMIT -1" {1 2 3 4 5 6 7 8 9 10}
2 "UPDATE t7 SET s = r WHERE q>4 LIMIT -1"
{1 2 3 4 five six seven eight nine ten}
3 "UPDATE t7 SET s = 'X' LIMIT -1" {X X X X X X X X X X}
}
# EVIDENCE-OF: R-18628-11938 If the LIMIT expression evaluates to
# non-negative value N and the UPDATE statement has an ORDER BY clause,
# then all rows that would be updated in the absence of the LIMIT clause
# are sorted according to the ORDER BY and the first N updated.
#
do_update_tests e_update-3.3 -query { SELECT s FROM t7 } {
1 "UPDATE t7 SET s = q ORDER BY r LIMIT 3" {X X X 4 5 X X 8 X X}
2 "UPDATE t7 SET s = r ORDER BY r DESC LIMIT 2" {X two three 4 5 X X 8 X X}
3 "UPDATE t7 SET s = q ORDER BY q DESC LIMIT 5" {X two three 4 5 6 7 8 9 10}
X "UPDATE t7 SET s = 'X'" {X X X X X X X X X X}
}
# EVIDENCE-OF: R-30955-38324 If the UPDATE statement also has an OFFSET
# clause, then it is similarly evaluated and cast to an integer value.
# If the OFFSET expression evaluates to a non-negative value M, then the
# first M rows are skipped and the following N rows updated instead.
#
do_update_tests e_update-3.3 -query { SELECT s FROM t7 } {
1 "UPDATE t7 SET s = q ORDER BY q LIMIT 3 OFFSET 2" {X X 3 4 5 X X X X X}
2 "UPDATE t7 SET s = q ORDER BY q DESC LIMIT 2, 3 " {X X 3 4 5 6 7 8 X X}
X "UPDATE t7 SET s = 'X'" {X X X X X X X X X X}
}
# EVIDENCE-OF: R-19486-35828 If the UPDATE statement has no ORDER BY
# clause, then all rows that would be updated in the absence of the
# LIMIT clause are assembled in an arbitrary order before applying the
# LIMIT and OFFSET clauses to determine which are actually updated.
#
# In practice, "arbitrary order" is rowid order. This is also tested
# by e_update-3.2.* above.
#
do_update_tests e_update-3.4 -query { SELECT s FROM t7 } {
1 "UPDATE t7 SET s = q LIMIT 4, 2" {X X X X 5 6 X X X X}
2 "UPDATE t7 SET s = q LIMIT 2 OFFSET 7" {X X X X 5 6 X 8 9 X}
}
# EVIDENCE-OF: R-10927-26133 The ORDER BY clause on an UPDATE statement
# is used only to determine which rows fall within the LIMIT. The order
# in which rows are modified is arbitrary and is not influenced by the
# ORDER BY clause.
#
do_execsql_test e_update-3.5.0 {
CREATE TABLE t8(x);
CREATE TRIGGER tr7 BEFORE UPDATE ON t7 BEGIN
INSERT INTO t8 VALUES(old.q);
END;
} {}
do_update_tests e_update-3.5 -query { SELECT x FROM t8 ; DELETE FROM t8 } {
1 "UPDATE t7 SET s = q ORDER BY r LIMIT -1" {1 2 3 4 5 6 7 8 9 10}
2 "UPDATE t7 SET s = q ORDER BY r ASC LIMIT -1" {1 2 3 4 5 6 7 8 9 10}
3 "UPDATE t7 SET s = q ORDER BY r DESC LIMIT -1" {1 2 3 4 5 6 7 8 9 10}
4 "UPDATE t7 SET s = q ORDER BY q DESC LIMIT 5" {6 7 8 9 10}
}
} ;# ifcapable update_delete_limit
finish_test