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 UPDATE statement.
14 # $Id: update.test,v 1.19 2008/04/10 18:44:36 drh Exp $
16 set testdir [file dirname $argv0]
17 source $testdir/tester.tcl
19 # Try to update an non-existent table
22 set v [catch {execsql {UPDATE test1 SET f2=5 WHERE f1<1}} msg]
24 } {1 {no such table: test1}}
26 # Try to update a read-only table
30 {execsql {UPDATE sqlite_master SET name='xyz' WHERE name='123'}} msg]
32 } {1 {table sqlite_master may not be modified}}
34 # Create a table to work with
37 execsql {CREATE TABLE test1(f1 int,f2 int)}
38 for {set i 1} {$i<=10} {incr i} {
39 set sql "INSERT INTO test1 VALUES($i,[expr {1<<$i}])"
42 execsql {SELECT * FROM test1 ORDER BY f1}
43 } {1 2 2 4 3 8 4 16 5 32 6 64 7 128 8 256 9 512 10 1024}
45 # Unknown column name in an expression
48 set v [catch {execsql {UPDATE test1 SET f1=f3*2 WHERE f2==32}} msg]
50 } {1 {no such column: f3}}
52 set v [catch {execsql {UPDATE test1 SET f1=test2.f1*2 WHERE f2==32}} msg]
54 } {1 {no such column: test2.f1}}
56 set v [catch {execsql {UPDATE test1 SET f3=f1*2 WHERE f2==32}} msg]
58 } {1 {no such column: f3}}
60 # Actually do some updates
63 execsql {UPDATE test1 SET f2=f2*3}
65 do_test update-3.5.1 {
69 # verify that SELECT does not reset the change counter
70 do_test update-3.5.2 {
71 db eval {SELECT count(*) FROM test1}
73 do_test update-3.5.3 {
78 execsql {SELECT * FROM test1 ORDER BY f1}
79 } {1 6 2 12 3 24 4 48 5 96 6 192 7 384 8 768 9 1536 10 3072}
81 execsql {PRAGMA count_changes=on}
82 execsql {UPDATE test1 SET f2=f2/3 WHERE f1<=5}
85 execsql {SELECT * FROM test1 ORDER BY f1}
86 } {1 2 2 4 3 8 4 16 5 32 6 192 7 384 8 768 9 1536 10 3072}
88 execsql {UPDATE test1 SET f2=f2/3 WHERE f1>5}
91 execsql {SELECT * FROM test1 ORDER BY f1}
92 } {1 2 2 4 3 8 4 16 5 32 6 64 7 128 8 256 9 512 10 1024}
94 # Swap the values of f1 and f2 for all elements
97 execsql {UPDATE test1 SET F2=f1, F1=f2}
100 execsql {SELECT * FROM test1 ORDER BY F1}
101 } {2 1 4 2 8 3 16 4 32 5 64 6 128 7 256 8 512 9 1024 10}
102 do_test update-3.13 {
103 execsql {PRAGMA count_changes=off}
104 execsql {UPDATE test1 SET F2=f1, F1=f2}
106 do_test update-3.14 {
107 execsql {SELECT * FROM test1 ORDER BY F1}
108 } {1 2 2 4 3 8 4 16 5 32 6 64 7 128 8 256 9 512 10 1024}
110 # Create duplicate entries and make sure updating still
115 DELETE FROM test1 WHERE f1<=5;
116 INSERT INTO test1(f1,f2) VALUES(8,88);
117 INSERT INTO test1(f1,f2) VALUES(8,888);
118 INSERT INTO test1(f1,f2) VALUES(77,128);
119 INSERT INTO test1(f1,f2) VALUES(777,128);
121 execsql {SELECT * FROM test1 ORDER BY f1,f2}
122 } {6 64 7 128 8 88 8 256 8 888 9 512 10 1024 77 128 777 128}
124 execsql {UPDATE test1 SET f2=f2+1 WHERE f1==8}
125 execsql {SELECT * FROM test1 ORDER BY f1,f2}
126 } {6 64 7 128 8 89 8 257 8 889 9 512 10 1024 77 128 777 128}
128 execsql {UPDATE test1 SET f2=f2-1 WHERE f1==8 and f2>800}
129 execsql {SELECT * FROM test1 ORDER BY f1,f2}
130 } {6 64 7 128 8 89 8 257 8 888 9 512 10 1024 77 128 777 128}
132 execsql {UPDATE test1 SET f2=f2-1 WHERE f1==8 and f2<800}
133 execsql {SELECT * FROM test1 ORDER BY f1,f2}
134 } {6 64 7 128 8 88 8 256 8 888 9 512 10 1024 77 128 777 128}
136 execsql {UPDATE test1 SET f1=f1+1 WHERE f2==128}
137 execsql {SELECT * FROM test1 ORDER BY f1,f2}
138 } {6 64 8 88 8 128 8 256 8 888 9 512 10 1024 78 128 778 128}
140 execsql {UPDATE test1 SET f1=f1-1 WHERE f1>100 and f2==128}
141 execsql {SELECT * FROM test1 ORDER BY f1,f2}
142 } {6 64 8 88 8 128 8 256 8 888 9 512 10 1024 78 128 777 128}
145 PRAGMA count_changes=on;
146 UPDATE test1 SET f1=f1-1 WHERE f1<=100 and f2==128;
151 PRAGMA count_changes=off;
152 SELECT * FROM test1 ORDER BY f1,f2
154 } {6 64 7 128 8 88 8 256 8 888 9 512 10 1024 77 128 777 128}
156 # Repeat the previous sequence of tests with an index.
159 execsql {CREATE INDEX idx1 ON test1(f1)}
160 execsql {SELECT * FROM test1 ORDER BY f1,f2}
161 } {6 64 7 128 8 88 8 256 8 888 9 512 10 1024 77 128 777 128}
163 execsql {UPDATE test1 SET f2=f2+1 WHERE f1==8}
164 execsql {SELECT * FROM test1 ORDER BY f1,f2}
165 } {6 64 7 128 8 89 8 257 8 889 9 512 10 1024 77 128 777 128}
167 execsql {UPDATE test1 SET f2=f2-1 WHERE f1==8 and f2>800}
168 execsql {SELECT * FROM test1 ORDER BY f1,f2}
169 } {6 64 7 128 8 89 8 257 8 888 9 512 10 1024 77 128 777 128}
171 execsql {UPDATE test1 SET f2=f2-1 WHERE f1==8 and f2<800}
172 execsql {SELECT * FROM test1 ORDER BY f1,f2}
173 } {6 64 7 128 8 88 8 256 8 888 9 512 10 1024 77 128 777 128}
175 execsql {UPDATE test1 SET f1=f1+1 WHERE f2==128}
176 execsql {SELECT * FROM test1 ORDER BY f1,f2}
177 } {6 64 8 88 8 128 8 256 8 888 9 512 10 1024 78 128 778 128}
178 do_test update-5.4.1 {
179 execsql {SELECT * FROM test1 WHERE f1==78 ORDER BY f1,f2}
181 do_test update-5.4.2 {
182 execsql {SELECT * FROM test1 WHERE f1==778 ORDER BY f1,f2}
184 do_test update-5.4.3 {
185 execsql {SELECT * FROM test1 WHERE f1==8 ORDER BY f1,f2}
186 } {8 88 8 128 8 256 8 888}
188 execsql {UPDATE test1 SET f1=f1-1 WHERE f1>100 and f2==128}
190 do_test update-5.5.1 {
191 execsql {SELECT * FROM test1 ORDER BY f1,f2}
192 } {6 64 8 88 8 128 8 256 8 888 9 512 10 1024 78 128 777 128}
193 do_test update-5.5.2 {
194 execsql {SELECT * FROM test1 WHERE f1==78 ORDER BY f1,f2}
196 do_test update-5.5.3 {
197 execsql {SELECT * FROM test1 WHERE f1==778 ORDER BY f1,f2}
199 do_test update-5.5.4 {
200 execsql {SELECT * FROM test1 WHERE f1==777 ORDER BY f1,f2}
202 do_test update-5.5.5 {
203 execsql {SELECT * FROM test1 WHERE f1==8 ORDER BY f1,f2}
204 } {8 88 8 128 8 256 8 888}
207 PRAGMA count_changes=on;
208 UPDATE test1 SET f1=f1-1 WHERE f1<=100 and f2==128;
211 do_test update-5.6.1 {
213 PRAGMA count_changes=off;
214 SELECT * FROM test1 ORDER BY f1,f2
216 } {6 64 7 128 8 88 8 256 8 888 9 512 10 1024 77 128 777 128}
217 do_test update-5.6.2 {
218 execsql {SELECT * FROM test1 WHERE f1==77 ORDER BY f1,f2}
220 do_test update-5.6.3 {
221 execsql {SELECT * FROM test1 WHERE f1==778 ORDER BY f1,f2}
223 do_test update-5.6.4 {
224 execsql {SELECT * FROM test1 WHERE f1==777 ORDER BY f1,f2}
226 do_test update-5.6.5 {
227 execsql {SELECT * FROM test1 WHERE f1==8 ORDER BY f1,f2}
230 # Repeat the previous sequence of tests with a different index.
232 execsql {PRAGMA synchronous=FULL}
234 execsql {DROP INDEX idx1}
235 execsql {CREATE INDEX idx1 ON test1(f2)}
236 execsql {SELECT * FROM test1 ORDER BY f1,f2}
237 } {6 64 7 128 8 88 8 256 8 888 9 512 10 1024 77 128 777 128}
239 execsql {UPDATE test1 SET f2=f2+1 WHERE f1==8}
240 execsql {SELECT * FROM test1 ORDER BY f1,f2}
241 } {6 64 7 128 8 89 8 257 8 889 9 512 10 1024 77 128 777 128}
242 do_test update-6.1.1 {
243 execsql {SELECT * FROM test1 WHERE f1==8 ORDER BY f1,f2}
245 do_test update-6.1.2 {
246 execsql {SELECT * FROM test1 WHERE f2==89 ORDER BY f1,f2}
248 do_test update-6.1.3 {
249 execsql {SELECT * FROM test1 WHERE f1==88 ORDER BY f1,f2}
252 execsql {UPDATE test1 SET f2=f2-1 WHERE f1==8 and f2>800}
253 execsql {SELECT * FROM test1 ORDER BY f1,f2}
254 } {6 64 7 128 8 89 8 257 8 888 9 512 10 1024 77 128 777 128}
256 execsql {UPDATE test1 SET f2=f2-1 WHERE f1==8 and f2<800}
257 execsql {SELECT * FROM test1 ORDER BY f1,f2}
258 } {6 64 7 128 8 88 8 256 8 888 9 512 10 1024 77 128 777 128}
259 do_test update-6.3.1 {
260 execsql {SELECT * FROM test1 WHERE f1==8 ORDER BY f1,f2}
262 do_test update-6.3.2 {
263 execsql {SELECT * FROM test1 WHERE f2==89 ORDER BY f1,f2}
265 do_test update-6.3.3 {
266 execsql {SELECT * FROM test1 WHERE f2==88 ORDER BY f1,f2}
269 execsql {UPDATE test1 SET f1=f1+1 WHERE f2==128}
270 execsql {SELECT * FROM test1 ORDER BY f1,f2}
271 } {6 64 8 88 8 128 8 256 8 888 9 512 10 1024 78 128 778 128}
272 do_test update-6.4.1 {
273 execsql {SELECT * FROM test1 WHERE f1==78 ORDER BY f1,f2}
275 do_test update-6.4.2 {
276 execsql {SELECT * FROM test1 WHERE f1==778 ORDER BY f1,f2}
278 do_test update-6.4.3 {
279 execsql {SELECT * FROM test1 WHERE f1==8 ORDER BY f1,f2}
280 } {8 88 8 128 8 256 8 888}
282 execsql {UPDATE test1 SET f1=f1-1 WHERE f1>100 and f2==128}
283 execsql {SELECT * FROM test1 ORDER BY f1,f2}
284 } {6 64 8 88 8 128 8 256 8 888 9 512 10 1024 78 128 777 128}
285 do_test update-6.5.1 {
286 execsql {SELECT * FROM test1 WHERE f1==78 ORDER BY f1,f2}
288 do_test update-6.5.2 {
289 execsql {SELECT * FROM test1 WHERE f1==778 ORDER BY f1,f2}
291 do_test update-6.5.3 {
292 execsql {SELECT * FROM test1 WHERE f1==777 ORDER BY f1,f2}
294 do_test update-6.5.4 {
295 execsql {SELECT * FROM test1 WHERE f1==8 ORDER BY f1,f2}
296 } {8 88 8 128 8 256 8 888}
298 execsql {UPDATE test1 SET f1=f1-1 WHERE f1<=100 and f2==128}
299 execsql {SELECT * FROM test1 ORDER BY f1,f2}
300 } {6 64 7 128 8 88 8 256 8 888 9 512 10 1024 77 128 777 128}
301 do_test update-6.6.1 {
302 execsql {SELECT * FROM test1 WHERE f1==77 ORDER BY f1,f2}
304 do_test update-6.6.2 {
305 execsql {SELECT * FROM test1 WHERE f1==778 ORDER BY f1,f2}
307 do_test update-6.6.3 {
308 execsql {SELECT * FROM test1 WHERE f1==777 ORDER BY f1,f2}
310 do_test update-6.6.4 {
311 execsql {SELECT * FROM test1 WHERE f1==8 ORDER BY f1,f2}
314 # Repeat the previous sequence of tests with multiple
318 execsql {CREATE INDEX idx2 ON test1(f2)}
319 execsql {CREATE INDEX idx3 ON test1(f1,f2)}
320 execsql {SELECT * FROM test1 ORDER BY f1,f2}
321 } {6 64 7 128 8 88 8 256 8 888 9 512 10 1024 77 128 777 128}
323 execsql {UPDATE test1 SET f2=f2+1 WHERE f1==8}
324 execsql {SELECT * FROM test1 ORDER BY f1,f2}
325 } {6 64 7 128 8 89 8 257 8 889 9 512 10 1024 77 128 777 128}
326 do_test update-7.1.1 {
327 execsql {SELECT * FROM test1 WHERE f1==8 ORDER BY f1,f2}
329 do_test update-7.1.2 {
330 execsql {SELECT * FROM test1 WHERE f2==89 ORDER BY f1,f2}
332 do_test update-7.1.3 {
333 execsql {SELECT * FROM test1 WHERE f1==88 ORDER BY f1,f2}
336 execsql {UPDATE test1 SET f2=f2-1 WHERE f1==8 and f2>800}
337 execsql {SELECT * FROM test1 ORDER BY f1,f2}
338 } {6 64 7 128 8 89 8 257 8 888 9 512 10 1024 77 128 777 128}
340 # explain {UPDATE test1 SET f2=f2-1 WHERE f1==8 and F2<300}
341 execsql {UPDATE test1 SET f2=f2-1 WHERE f1==8 and f2<800}
342 execsql {SELECT * FROM test1 ORDER BY f1,f2}
343 } {6 64 7 128 8 88 8 256 8 888 9 512 10 1024 77 128 777 128}
344 do_test update-7.3.1 {
345 execsql {SELECT * FROM test1 WHERE f1==8 ORDER BY f1,f2}
347 do_test update-7.3.2 {
348 execsql {SELECT * FROM test1 WHERE f2==89 ORDER BY f1,f2}
350 do_test update-7.3.3 {
351 execsql {SELECT * FROM test1 WHERE f2==88 ORDER BY f1,f2}
354 execsql {UPDATE test1 SET f1=f1+1 WHERE f2==128}
355 execsql {SELECT * FROM test1 ORDER BY f1,f2}
356 } {6 64 8 88 8 128 8 256 8 888 9 512 10 1024 78 128 778 128}
357 do_test update-7.4.1 {
358 execsql {SELECT * FROM test1 WHERE f1==78 ORDER BY f1,f2}
360 do_test update-7.4.2 {
361 execsql {SELECT * FROM test1 WHERE f1==778 ORDER BY f1,f2}
363 do_test update-7.4.3 {
364 execsql {SELECT * FROM test1 WHERE f1==8 ORDER BY f1,f2}
365 } {8 88 8 128 8 256 8 888}
367 execsql {UPDATE test1 SET f1=f1-1 WHERE f1>100 and f2==128}
368 execsql {SELECT * FROM test1 ORDER BY f1,f2}
369 } {6 64 8 88 8 128 8 256 8 888 9 512 10 1024 78 128 777 128}
370 do_test update-7.5.1 {
371 execsql {SELECT * FROM test1 WHERE f1==78 ORDER BY f1,f2}
373 do_test update-7.5.2 {
374 execsql {SELECT * FROM test1 WHERE f1==778 ORDER BY f1,f2}
376 do_test update-7.5.3 {
377 execsql {SELECT * FROM test1 WHERE f1==777 ORDER BY f1,f2}
379 do_test update-7.5.4 {
380 execsql {SELECT * FROM test1 WHERE f1==8 ORDER BY f1,f2}
381 } {8 88 8 128 8 256 8 888}
383 execsql {UPDATE test1 SET f1=f1-1 WHERE f1<=100 and f2==128}
384 execsql {SELECT * FROM test1 ORDER BY f1,f2}
385 } {6 64 7 128 8 88 8 256 8 888 9 512 10 1024 77 128 777 128}
386 do_test update-7.6.1 {
387 execsql {SELECT * FROM test1 WHERE f1==77 ORDER BY f1,f2}
389 do_test update-7.6.2 {
390 execsql {SELECT * FROM test1 WHERE f1==778 ORDER BY f1,f2}
392 do_test update-7.6.3 {
393 execsql {SELECT * FROM test1 WHERE f1==777 ORDER BY f1,f2}
395 do_test update-7.6.4 {
396 execsql {SELECT * FROM test1 WHERE f1==8 ORDER BY f1,f2}
402 set v [catch {execsql {
403 UPDATE test1 SET x=11 WHERE f1=1025
406 } {1 {no such column: x}}
408 set v [catch {execsql {
409 UPDATE test1 SET f1=x(11) WHERE f1=1025
412 } {1 {no such function: x}}
414 set v [catch {execsql {
415 UPDATE test1 SET f1=11 WHERE x=1025
418 } {1 {no such column: x}}
420 set v [catch {execsql {
421 UPDATE test1 SET f1=11 WHERE x(f1)=1025
424 } {1 {no such function: x}}
426 # Try doing updates on a unique column where the value does not
429 do_test update-10.1 {
433 a integer primary key,
439 INSERT INTO t1 VALUES(1,2,3,4,5,6);
440 INSERT INTO t1 VALUES(2,3,4,4,6,7);
443 } {1 2 3 4 5 6 2 3 4 4 6 7}
444 do_test update-10.2 {
446 UPDATE t1 SET a=1, e=9 WHERE f=6;
449 } {0 {1 2 3 4 9 6 2 3 4 4 6 7}}
450 do_test update-10.3 {
452 UPDATE t1 SET a=1, e=10 WHERE f=7;
455 } {1 {UNIQUE constraint failed: t1.a}}
456 do_test update-10.4 {
460 } {0 {1 2 3 4 9 6 2 3 4 4 6 7}}
461 do_test update-10.5 {
463 UPDATE t1 SET b=2, e=11 WHERE f=6;
466 } {0 {1 2 3 4 11 6 2 3 4 4 6 7}}
467 do_test update-10.6 {
469 UPDATE t1 SET b=2, e=12 WHERE f=7;
472 } {1 {UNIQUE constraint failed: t1.b}}
473 do_test update-10.7 {
477 } {0 {1 2 3 4 11 6 2 3 4 4 6 7}}
478 do_test update-10.8 {
480 UPDATE t1 SET c=3, d=4, e=13 WHERE f=6;
483 } {0 {1 2 3 4 13 6 2 3 4 4 6 7}}
484 do_test update-10.9 {
486 UPDATE t1 SET c=3, d=4, e=14 WHERE f=7;
489 } {1 {UNIQUE constraint failed: t1.c, t1.d}}
490 do_test update-10.10 {
494 } {0 {1 2 3 4 13 6 2 3 4 4 6 7}}
496 # Make sure we can handle a subquery in the where clause.
499 do_test update-11.1 {
501 UPDATE t1 SET e=e+1 WHERE b IN (SELECT b FROM t1);
505 do_test update-11.2 {
507 UPDATE t1 SET e=e+1 WHERE a IN (SELECT a FROM t1);
511 do_test update-11.3 {
513 UPDATE t1 AS xyz SET e=e+1 WHERE xyz.a IN (SELECT a FROM t1);
517 do_test update-11.4 {
519 UPDATE t1 AS xyz SET e=e+1 WHERE EXISTS(SELECT 1 FROM t1 WHERE t1.a<xyz.a);
525 integrity_check update-12.1
527 # Ticket 602. Updates should occur in the same order as the records
528 # were discovered in the WHERE clause.
530 do_test update-13.1 {
534 INSERT INTO t2 VALUES(1);
535 INSERT INTO t2 VALUES(2);
536 INSERT INTO t2 SELECT a+2 FROM t2;
537 INSERT INTO t2 SELECT a+4 FROM t2;
538 INSERT INTO t2 SELECT a+8 FROM t2;
539 INSERT INTO t2 SELECT a+16 FROM t2;
540 INSERT INTO t2 SELECT a+32 FROM t2;
541 INSERT INTO t2 SELECT a+64 FROM t2;
542 INSERT INTO t2 SELECT a+128 FROM t2;
543 INSERT INTO t2 SELECT a+256 FROM t2;
544 INSERT INTO t2 SELECT a+512 FROM t2;
545 INSERT INTO t2 SELECT a+1024 FROM t2;
547 SELECT count(*) FROM t2;
550 do_test update-13.2 {
552 SELECT count(*) FROM t2 WHERE a=rowid;
555 do_test update-13.3 {
557 UPDATE t2 SET rowid=rowid-1;
558 SELECT count(*) FROM t2 WHERE a=rowid+1;
561 do_test update-13.3 {
563 UPDATE t2 SET rowid=rowid+10000;
564 UPDATE t2 SET rowid=rowid-9999;
565 SELECT count(*) FROM t2 WHERE a=rowid;
568 do_test update-13.4 {
571 INSERT INTO t2 SELECT a+2048 FROM t2;
572 INSERT INTO t2 SELECT a+4096 FROM t2;
573 INSERT INTO t2 SELECT a+8192 FROM t2;
574 SELECT count(*) FROM t2 WHERE a=rowid;
578 do_test update-13.5 {
580 UPDATE t2 SET rowid=rowid-1;
581 SELECT count(*) FROM t2 WHERE a=rowid+1;
585 integrity_check update-13.6
587 ifcapable {trigger} {
588 # Test for proper detection of malformed WHEN clauses on UPDATE triggers.
590 do_test update-14.1 {
592 CREATE TABLE t3(a,b,c);
593 CREATE TRIGGER t3r1 BEFORE UPDATE on t3 WHEN nosuchcol BEGIN
594 SELECT 'illegal WHEN clause';
598 do_test update-14.2 {
602 } {1 {no such column: nosuchcol}}
603 do_test update-14.3 {
605 CREATE TABLE t4(a,b,c);
606 CREATE TRIGGER t4r1 AFTER UPDATE on t4 WHEN nosuchcol BEGIN
607 SELECT 'illegal WHEN clause';
611 do_test update-14.4 {
615 } {1 {no such column: nosuchcol}}
617 } ;# ifcapable {trigger}
619 # Ticket [https://www.sqlite.org/src/tktview/43107840f1c02] on 2014-10-29
620 # An assertion fault on UPDATE
622 ifcapable altertable {
623 do_execsql_test update-15.1 {
624 CREATE TABLE t15(a INTEGER PRIMARY KEY, b);
625 INSERT INTO t15(a,b) VALUES(10,'abc'),(20,'def'),(30,'ghi');
626 ALTER TABLE t15 ADD COLUMN c;
627 CREATE INDEX t15c ON t15(c);
629 VALUES(5,'zyx'),(15,'wvu'),(25,'tsr'),(35,'qpo');
630 UPDATE t15 SET c=printf('y%d',a) WHERE c IS NULL;
631 SELECT a,b,c,'|' FROM t15 ORDER BY a;
632 } {5 zyx y5 | 10 abc y10 | 15 wvu y15 | 20 def y20 | 25 tsr y25 | 30 ghi y30 | 35 qpo y35 |}
635 # Unreleased bug in UPDATE caused by the UPSERT changes.
636 # Found by OSSFuzz as soon as the UPSERT changes landed on trunk.
637 # Never released into the wild. 2018-04-19.
639 do_execsql_test update-16.1 {
640 CREATE TABLE t16(a INTEGER PRIMARY KEY ON CONFLICT REPLACE, b UNIQUE);
641 INSERT INTO t16(a,b) VALUES(1,2),(3,4),(5,6);
643 SELECT * FROM t16 ORDER BY +a;
646 # 2019-12-09 gramfuzz find
647 # If a partial index that does not reference any column of its table (which is you
648 # must admit is a very strange index, but one that is allowed) is used by an UPDATE
649 # statement, void the use of OP_DeferredSeek on the main loop, as the seek will not
650 # be resolved prior to the OP_Delete.
652 do_execsql_test update-17.10 {
653 DROP TABLE IF EXISTS t1;
654 CREATE TABLE t1(x,y);
655 INSERT INTO t1(x) VALUES(1);
656 CREATE INDEX t1x1 ON t1(1) WHERE 3;
657 UPDATE t1 SET x=2, y=3 WHERE 3;
661 # 2019-12-22 ticket 5ad2aa6921faa1ee
662 # Make a hard-copy of values that need to be run through OP_RealAffinity
663 # rather than a soft-copy. This is not strictly necessary, but it avoids
664 # a memory-accounting assert().
667 do_execsql_test update-18.10 {
668 PRAGMA encoding = 'UTF16';
669 CREATE TABLE t0(c0 REAL, c1);
670 INSERT INTO t0(c0,c1) VALUES('xyz',11),('uvw',22);
671 CREATE INDEX i0 ON t0(c1) WHERE c0 GLOB 3;
672 CREATE INDEX i1 ON t0(c0,c1) WHERE typeof(c0)='text' AND typeof(c1)='integer';
673 UPDATE t0 SET c1=345;
677 # 2019-12-22 ticket c62c5e58524b204d
678 # This is really the same underlying problem as 5ad2aa6921faa1ee
681 do_execsql_test update-18.20 {
682 PRAGMA encoding = 'utf16';
683 CREATE TABLE t0(c0 TEXT);
684 CREATE INDEX i0 ON t0(0 LIKE COALESCE(c0, 0));
685 INSERT INTO t0(c0) VALUES (0), (0);
689 # 2019-12-28 assertion fault reported by Yongheng
690 # Similar to ticket ec8abb025e78f40c
691 # An UPDATE was reaching the OP_Delete after running OP_DeferredSeek
692 # without ever hitting an OP_Column. The enhanced solution is to
693 # fix OP_Delete so that it can do the seek itself.
696 do_execsql_test update-19.10 {
699 b INTEGER PRIMARY KEY UNIQUE
701 INSERT INTO t1 VALUES(1,2);
702 UPDATE t1 SET a = quote(b) WHERE b>=2;
706 # 2019-12-29 ticket https://www.sqlite.org/src/info/314cc133e5ada126
707 # REPLACE conflict resolution during an UPDATE causes a DELETE trigger
708 # to fire. If that DELETE trigger subsequently modifies the row
709 # being updated, bad things can happen. Prevent this by prohibiting
710 # triggers from making changes to the table being updated while doing
711 # REPLACE conflict resolution on the UPDATE.
714 # https://www.sqlite.org/src/info/c1e19e12046d23fe 2019-10-25
715 # https://www.sqlite.org/src/info/a8a4847a2d96f5de 2019-10-16
718 do_execsql_test update-20.10 {
719 PRAGMA recursive_triggers = true;
720 CREATE TABLE t1(a UNIQUE ON CONFLICT REPLACE, b);
721 INSERT INTO t1(a,b) VALUES(4,12),(9,13);
722 CREATE INDEX i0 ON t1(b);
723 CREATE TRIGGER tr0 DELETE ON t1 BEGIN
726 PRAGMA integrity_check;
728 do_catchsql_test update-20.20 {
730 } {1 {constraint failed}}
731 do_execsql_test update-20.30 {
732 PRAGMA integrity_check;
735 # 2023-03-16 https://sqlite.org/forum/forumpost/0007d1fdb1
736 # A subquery in the WHERE clause of an UPDATE and behind a
737 # short-circuit evaluation caused problems because multi-row
738 # single-pass was selected.
740 # Similar problem for DELETE tested by delete-12.0.
741 # https://sqlite.org/src/info/73f0036f045bf371
744 do_execsql_test update-21.1 {
745 CREATE TABLE t1 (vkey INTEGER, c5 INTEGER);
746 INSERT INTO t1 VALUES(3,NULL),(6,-54);
749 do_execsql_test update-21.2 {
751 UPDATE t1 SET vkey = 100 WHERE c5 is null;
752 SELECT * FROM t1 ORDER BY vkey, c5;
755 do_execsql_test update-21.3 {
757 UPDATE t1 SET vkey = 100 WHERE NOT (-10*(select min(vkey) from t1) >= c5);
758 SELECT * FROM t1 ORDER BY vkey, c5;
761 do_execsql_test update-21.4 {
763 UPDATE t1 SET vkey = 100 WHERE c5 is null OR NOT (-10*(select min(vkey) from t1) >= c5);
764 SELECT * FROM t1 ORDER BY vkey, c5;
767 # Follow-up on 2023-07-31 (forum post https://sqlite.org/forum/forumpost/8ab195fd44e75ed0):
768 # Only disable one-pass if the subquery is in the WHERE clause. The SET expressions
770 do_execsql_test update-21.11 {
772 CREATE TABLE t1(a INTEGER PRIMARY KEY, b INT);
773 CREATE TABLE t2(d INT);
775 do_eqp_test update-21.12 {
776 WITH t3(x,y) AS (SELECT d, row_number()OVER() FROM t2)
777 UPDATE t1 SET b=(SELECT y FROM t3 WHERE t1.a=t3.x);
781 `--CORRELATED SCALAR SUBQUERY xxxxxx
783 | |--CO-ROUTINE (subquery-xxxxxx)
785 | `--SCAN (subquery-xxxxxx)
786 |--BLOOM FILTER ON t3 (x=?)
787 `--SEARCH t3 USING AUTOMATIC COVERING INDEX (x=?)