e_update.test 20 KB

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