sqlite/test/update.test
drh d192b4441d Restore part of the UPDATE one-pass optimization that was removed by
check-in [2c56b984a0bd3be5]: only disable one-pass if the WHERE clause
contains a subquery.  Allow subqueries in the SET expressions.
Fix for performance problem reported by
[forum:/forumpost/8ab195fd44e75ed0|forum  post 8ab195fd44e75ed0].

FossilOrigin-Name: 42916af9fc0f379a608a08db894400bd735a28e26ab1ffd604d1fddfbdb3ec0c
2023-08-01 00:34:03 +00:00

791 lines
24 KiB
Plaintext

# 2001 September 15
#
# 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 regression tests for SQLite library. The
# focus of this file is testing the UPDATE statement.
#
# $Id: update.test,v 1.19 2008/04/10 18:44:36 drh Exp $
set testdir [file dirname $argv0]
source $testdir/tester.tcl
# Try to update an non-existent table
#
do_test update-1.1 {
set v [catch {execsql {UPDATE test1 SET f2=5 WHERE f1<1}} msg]
lappend v $msg
} {1 {no such table: test1}}
# Try to update a read-only table
#
do_test update-2.1 {
set v [catch \
{execsql {UPDATE sqlite_master SET name='xyz' WHERE name='123'}} msg]
lappend v $msg
} {1 {table sqlite_master may not be modified}}
# Create a table to work with
#
do_test update-3.1 {
execsql {CREATE TABLE test1(f1 int,f2 int)}
for {set i 1} {$i<=10} {incr i} {
set sql "INSERT INTO test1 VALUES($i,[expr {1<<$i}])"
execsql $sql
}
execsql {SELECT * FROM test1 ORDER BY f1}
} {1 2 2 4 3 8 4 16 5 32 6 64 7 128 8 256 9 512 10 1024}
# Unknown column name in an expression
#
do_test update-3.2 {
set v [catch {execsql {UPDATE test1 SET f1=f3*2 WHERE f2==32}} msg]
lappend v $msg
} {1 {no such column: f3}}
do_test update-3.3 {
set v [catch {execsql {UPDATE test1 SET f1=test2.f1*2 WHERE f2==32}} msg]
lappend v $msg
} {1 {no such column: test2.f1}}
do_test update-3.4 {
set v [catch {execsql {UPDATE test1 SET f3=f1*2 WHERE f2==32}} msg]
lappend v $msg
} {1 {no such column: f3}}
# Actually do some updates
#
do_test update-3.5 {
execsql {UPDATE test1 SET f2=f2*3}
} {}
do_test update-3.5.1 {
db changes
} {10}
# verify that SELECT does not reset the change counter
do_test update-3.5.2 {
db eval {SELECT count(*) FROM test1}
} {10}
do_test update-3.5.3 {
db changes
} {10}
do_test update-3.6 {
execsql {SELECT * FROM test1 ORDER BY f1}
} {1 6 2 12 3 24 4 48 5 96 6 192 7 384 8 768 9 1536 10 3072}
do_test update-3.7 {
execsql {PRAGMA count_changes=on}
execsql {UPDATE test1 SET f2=f2/3 WHERE f1<=5}
} {5}
do_test update-3.8 {
execsql {SELECT * FROM test1 ORDER BY f1}
} {1 2 2 4 3 8 4 16 5 32 6 192 7 384 8 768 9 1536 10 3072}
do_test update-3.9 {
execsql {UPDATE test1 SET f2=f2/3 WHERE f1>5}
} {5}
do_test update-3.10 {
execsql {SELECT * FROM test1 ORDER BY f1}
} {1 2 2 4 3 8 4 16 5 32 6 64 7 128 8 256 9 512 10 1024}
# Swap the values of f1 and f2 for all elements
#
do_test update-3.11 {
execsql {UPDATE test1 SET F2=f1, F1=f2}
} {10}
do_test update-3.12 {
execsql {SELECT * FROM test1 ORDER BY F1}
} {2 1 4 2 8 3 16 4 32 5 64 6 128 7 256 8 512 9 1024 10}
do_test update-3.13 {
execsql {PRAGMA count_changes=off}
execsql {UPDATE test1 SET F2=f1, F1=f2}
} {}
do_test update-3.14 {
execsql {SELECT * FROM test1 ORDER BY F1}
} {1 2 2 4 3 8 4 16 5 32 6 64 7 128 8 256 9 512 10 1024}
# Create duplicate entries and make sure updating still
# works.
#
do_test update-4.0 {
execsql {
DELETE FROM test1 WHERE f1<=5;
INSERT INTO test1(f1,f2) VALUES(8,88);
INSERT INTO test1(f1,f2) VALUES(8,888);
INSERT INTO test1(f1,f2) VALUES(77,128);
INSERT INTO test1(f1,f2) VALUES(777,128);
}
execsql {SELECT * FROM test1 ORDER BY f1,f2}
} {6 64 7 128 8 88 8 256 8 888 9 512 10 1024 77 128 777 128}
do_test update-4.1 {
execsql {UPDATE test1 SET f2=f2+1 WHERE f1==8}
execsql {SELECT * FROM test1 ORDER BY f1,f2}
} {6 64 7 128 8 89 8 257 8 889 9 512 10 1024 77 128 777 128}
do_test update-4.2 {
execsql {UPDATE test1 SET f2=f2-1 WHERE f1==8 and f2>800}
execsql {SELECT * FROM test1 ORDER BY f1,f2}
} {6 64 7 128 8 89 8 257 8 888 9 512 10 1024 77 128 777 128}
do_test update-4.3 {
execsql {UPDATE test1 SET f2=f2-1 WHERE f1==8 and f2<800}
execsql {SELECT * FROM test1 ORDER BY f1,f2}
} {6 64 7 128 8 88 8 256 8 888 9 512 10 1024 77 128 777 128}
do_test update-4.4 {
execsql {UPDATE test1 SET f1=f1+1 WHERE f2==128}
execsql {SELECT * FROM test1 ORDER BY f1,f2}
} {6 64 8 88 8 128 8 256 8 888 9 512 10 1024 78 128 778 128}
do_test update-4.5 {
execsql {UPDATE test1 SET f1=f1-1 WHERE f1>100 and f2==128}
execsql {SELECT * FROM test1 ORDER BY f1,f2}
} {6 64 8 88 8 128 8 256 8 888 9 512 10 1024 78 128 777 128}
do_test update-4.6 {
execsql {
PRAGMA count_changes=on;
UPDATE test1 SET f1=f1-1 WHERE f1<=100 and f2==128;
}
} {2}
do_test update-4.7 {
execsql {
PRAGMA count_changes=off;
SELECT * FROM test1 ORDER BY f1,f2
}
} {6 64 7 128 8 88 8 256 8 888 9 512 10 1024 77 128 777 128}
# Repeat the previous sequence of tests with an index.
#
do_test update-5.0 {
execsql {CREATE INDEX idx1 ON test1(f1)}
execsql {SELECT * FROM test1 ORDER BY f1,f2}
} {6 64 7 128 8 88 8 256 8 888 9 512 10 1024 77 128 777 128}
do_test update-5.1 {
execsql {UPDATE test1 SET f2=f2+1 WHERE f1==8}
execsql {SELECT * FROM test1 ORDER BY f1,f2}
} {6 64 7 128 8 89 8 257 8 889 9 512 10 1024 77 128 777 128}
do_test update-5.2 {
execsql {UPDATE test1 SET f2=f2-1 WHERE f1==8 and f2>800}
execsql {SELECT * FROM test1 ORDER BY f1,f2}
} {6 64 7 128 8 89 8 257 8 888 9 512 10 1024 77 128 777 128}
do_test update-5.3 {
execsql {UPDATE test1 SET f2=f2-1 WHERE f1==8 and f2<800}
execsql {SELECT * FROM test1 ORDER BY f1,f2}
} {6 64 7 128 8 88 8 256 8 888 9 512 10 1024 77 128 777 128}
do_test update-5.4 {
execsql {UPDATE test1 SET f1=f1+1 WHERE f2==128}
execsql {SELECT * FROM test1 ORDER BY f1,f2}
} {6 64 8 88 8 128 8 256 8 888 9 512 10 1024 78 128 778 128}
do_test update-5.4.1 {
execsql {SELECT * FROM test1 WHERE f1==78 ORDER BY f1,f2}
} {78 128}
do_test update-5.4.2 {
execsql {SELECT * FROM test1 WHERE f1==778 ORDER BY f1,f2}
} {778 128}
do_test update-5.4.3 {
execsql {SELECT * FROM test1 WHERE f1==8 ORDER BY f1,f2}
} {8 88 8 128 8 256 8 888}
do_test update-5.5 {
execsql {UPDATE test1 SET f1=f1-1 WHERE f1>100 and f2==128}
} {}
do_test update-5.5.1 {
execsql {SELECT * FROM test1 ORDER BY f1,f2}
} {6 64 8 88 8 128 8 256 8 888 9 512 10 1024 78 128 777 128}
do_test update-5.5.2 {
execsql {SELECT * FROM test1 WHERE f1==78 ORDER BY f1,f2}
} {78 128}
do_test update-5.5.3 {
execsql {SELECT * FROM test1 WHERE f1==778 ORDER BY f1,f2}
} {}
do_test update-5.5.4 {
execsql {SELECT * FROM test1 WHERE f1==777 ORDER BY f1,f2}
} {777 128}
do_test update-5.5.5 {
execsql {SELECT * FROM test1 WHERE f1==8 ORDER BY f1,f2}
} {8 88 8 128 8 256 8 888}
do_test update-5.6 {
execsql {
PRAGMA count_changes=on;
UPDATE test1 SET f1=f1-1 WHERE f1<=100 and f2==128;
}
} {2}
do_test update-5.6.1 {
execsql {
PRAGMA count_changes=off;
SELECT * FROM test1 ORDER BY f1,f2
}
} {6 64 7 128 8 88 8 256 8 888 9 512 10 1024 77 128 777 128}
do_test update-5.6.2 {
execsql {SELECT * FROM test1 WHERE f1==77 ORDER BY f1,f2}
} {77 128}
do_test update-5.6.3 {
execsql {SELECT * FROM test1 WHERE f1==778 ORDER BY f1,f2}
} {}
do_test update-5.6.4 {
execsql {SELECT * FROM test1 WHERE f1==777 ORDER BY f1,f2}
} {777 128}
do_test update-5.6.5 {
execsql {SELECT * FROM test1 WHERE f1==8 ORDER BY f1,f2}
} {8 88 8 256 8 888}
# Repeat the previous sequence of tests with a different index.
#
execsql {PRAGMA synchronous=FULL}
do_test update-6.0 {
execsql {DROP INDEX idx1}
execsql {CREATE INDEX idx1 ON test1(f2)}
execsql {SELECT * FROM test1 ORDER BY f1,f2}
} {6 64 7 128 8 88 8 256 8 888 9 512 10 1024 77 128 777 128}
do_test update-6.1 {
execsql {UPDATE test1 SET f2=f2+1 WHERE f1==8}
execsql {SELECT * FROM test1 ORDER BY f1,f2}
} {6 64 7 128 8 89 8 257 8 889 9 512 10 1024 77 128 777 128}
do_test update-6.1.1 {
execsql {SELECT * FROM test1 WHERE f1==8 ORDER BY f1,f2}
} {8 89 8 257 8 889}
do_test update-6.1.2 {
execsql {SELECT * FROM test1 WHERE f2==89 ORDER BY f1,f2}
} {8 89}
do_test update-6.1.3 {
execsql {SELECT * FROM test1 WHERE f1==88 ORDER BY f1,f2}
} {}
do_test update-6.2 {
execsql {UPDATE test1 SET f2=f2-1 WHERE f1==8 and f2>800}
execsql {SELECT * FROM test1 ORDER BY f1,f2}
} {6 64 7 128 8 89 8 257 8 888 9 512 10 1024 77 128 777 128}
do_test update-6.3 {
execsql {UPDATE test1 SET f2=f2-1 WHERE f1==8 and f2<800}
execsql {SELECT * FROM test1 ORDER BY f1,f2}
} {6 64 7 128 8 88 8 256 8 888 9 512 10 1024 77 128 777 128}
do_test update-6.3.1 {
execsql {SELECT * FROM test1 WHERE f1==8 ORDER BY f1,f2}
} {8 88 8 256 8 888}
do_test update-6.3.2 {
execsql {SELECT * FROM test1 WHERE f2==89 ORDER BY f1,f2}
} {}
do_test update-6.3.3 {
execsql {SELECT * FROM test1 WHERE f2==88 ORDER BY f1,f2}
} {8 88}
do_test update-6.4 {
execsql {UPDATE test1 SET f1=f1+1 WHERE f2==128}
execsql {SELECT * FROM test1 ORDER BY f1,f2}
} {6 64 8 88 8 128 8 256 8 888 9 512 10 1024 78 128 778 128}
do_test update-6.4.1 {
execsql {SELECT * FROM test1 WHERE f1==78 ORDER BY f1,f2}
} {78 128}
do_test update-6.4.2 {
execsql {SELECT * FROM test1 WHERE f1==778 ORDER BY f1,f2}
} {778 128}
do_test update-6.4.3 {
execsql {SELECT * FROM test1 WHERE f1==8 ORDER BY f1,f2}
} {8 88 8 128 8 256 8 888}
do_test update-6.5 {
execsql {UPDATE test1 SET f1=f1-1 WHERE f1>100 and f2==128}
execsql {SELECT * FROM test1 ORDER BY f1,f2}
} {6 64 8 88 8 128 8 256 8 888 9 512 10 1024 78 128 777 128}
do_test update-6.5.1 {
execsql {SELECT * FROM test1 WHERE f1==78 ORDER BY f1,f2}
} {78 128}
do_test update-6.5.2 {
execsql {SELECT * FROM test1 WHERE f1==778 ORDER BY f1,f2}
} {}
do_test update-6.5.3 {
execsql {SELECT * FROM test1 WHERE f1==777 ORDER BY f1,f2}
} {777 128}
do_test update-6.5.4 {
execsql {SELECT * FROM test1 WHERE f1==8 ORDER BY f1,f2}
} {8 88 8 128 8 256 8 888}
do_test update-6.6 {
execsql {UPDATE test1 SET f1=f1-1 WHERE f1<=100 and f2==128}
execsql {SELECT * FROM test1 ORDER BY f1,f2}
} {6 64 7 128 8 88 8 256 8 888 9 512 10 1024 77 128 777 128}
do_test update-6.6.1 {
execsql {SELECT * FROM test1 WHERE f1==77 ORDER BY f1,f2}
} {77 128}
do_test update-6.6.2 {
execsql {SELECT * FROM test1 WHERE f1==778 ORDER BY f1,f2}
} {}
do_test update-6.6.3 {
execsql {SELECT * FROM test1 WHERE f1==777 ORDER BY f1,f2}
} {777 128}
do_test update-6.6.4 {
execsql {SELECT * FROM test1 WHERE f1==8 ORDER BY f1,f2}
} {8 88 8 256 8 888}
# Repeat the previous sequence of tests with multiple
# indices
#
do_test update-7.0 {
execsql {CREATE INDEX idx2 ON test1(f2)}
execsql {CREATE INDEX idx3 ON test1(f1,f2)}
execsql {SELECT * FROM test1 ORDER BY f1,f2}
} {6 64 7 128 8 88 8 256 8 888 9 512 10 1024 77 128 777 128}
do_test update-7.1 {
execsql {UPDATE test1 SET f2=f2+1 WHERE f1==8}
execsql {SELECT * FROM test1 ORDER BY f1,f2}
} {6 64 7 128 8 89 8 257 8 889 9 512 10 1024 77 128 777 128}
do_test update-7.1.1 {
execsql {SELECT * FROM test1 WHERE f1==8 ORDER BY f1,f2}
} {8 89 8 257 8 889}
do_test update-7.1.2 {
execsql {SELECT * FROM test1 WHERE f2==89 ORDER BY f1,f2}
} {8 89}
do_test update-7.1.3 {
execsql {SELECT * FROM test1 WHERE f1==88 ORDER BY f1,f2}
} {}
do_test update-7.2 {
execsql {UPDATE test1 SET f2=f2-1 WHERE f1==8 and f2>800}
execsql {SELECT * FROM test1 ORDER BY f1,f2}
} {6 64 7 128 8 89 8 257 8 888 9 512 10 1024 77 128 777 128}
do_test update-7.3 {
# explain {UPDATE test1 SET f2=f2-1 WHERE f1==8 and F2<300}
execsql {UPDATE test1 SET f2=f2-1 WHERE f1==8 and f2<800}
execsql {SELECT * FROM test1 ORDER BY f1,f2}
} {6 64 7 128 8 88 8 256 8 888 9 512 10 1024 77 128 777 128}
do_test update-7.3.1 {
execsql {SELECT * FROM test1 WHERE f1==8 ORDER BY f1,f2}
} {8 88 8 256 8 888}
do_test update-7.3.2 {
execsql {SELECT * FROM test1 WHERE f2==89 ORDER BY f1,f2}
} {}
do_test update-7.3.3 {
execsql {SELECT * FROM test1 WHERE f2==88 ORDER BY f1,f2}
} {8 88}
do_test update-7.4 {
execsql {UPDATE test1 SET f1=f1+1 WHERE f2==128}
execsql {SELECT * FROM test1 ORDER BY f1,f2}
} {6 64 8 88 8 128 8 256 8 888 9 512 10 1024 78 128 778 128}
do_test update-7.4.1 {
execsql {SELECT * FROM test1 WHERE f1==78 ORDER BY f1,f2}
} {78 128}
do_test update-7.4.2 {
execsql {SELECT * FROM test1 WHERE f1==778 ORDER BY f1,f2}
} {778 128}
do_test update-7.4.3 {
execsql {SELECT * FROM test1 WHERE f1==8 ORDER BY f1,f2}
} {8 88 8 128 8 256 8 888}
do_test update-7.5 {
execsql {UPDATE test1 SET f1=f1-1 WHERE f1>100 and f2==128}
execsql {SELECT * FROM test1 ORDER BY f1,f2}
} {6 64 8 88 8 128 8 256 8 888 9 512 10 1024 78 128 777 128}
do_test update-7.5.1 {
execsql {SELECT * FROM test1 WHERE f1==78 ORDER BY f1,f2}
} {78 128}
do_test update-7.5.2 {
execsql {SELECT * FROM test1 WHERE f1==778 ORDER BY f1,f2}
} {}
do_test update-7.5.3 {
execsql {SELECT * FROM test1 WHERE f1==777 ORDER BY f1,f2}
} {777 128}
do_test update-7.5.4 {
execsql {SELECT * FROM test1 WHERE f1==8 ORDER BY f1,f2}
} {8 88 8 128 8 256 8 888}
do_test update-7.6 {
execsql {UPDATE test1 SET f1=f1-1 WHERE f1<=100 and f2==128}
execsql {SELECT * FROM test1 ORDER BY f1,f2}
} {6 64 7 128 8 88 8 256 8 888 9 512 10 1024 77 128 777 128}
do_test update-7.6.1 {
execsql {SELECT * FROM test1 WHERE f1==77 ORDER BY f1,f2}
} {77 128}
do_test update-7.6.2 {
execsql {SELECT * FROM test1 WHERE f1==778 ORDER BY f1,f2}
} {}
do_test update-7.6.3 {
execsql {SELECT * FROM test1 WHERE f1==777 ORDER BY f1,f2}
} {777 128}
do_test update-7.6.4 {
execsql {SELECT * FROM test1 WHERE f1==8 ORDER BY f1,f2}
} {8 88 8 256 8 888}
# Error messages
#
do_test update-9.1 {
set v [catch {execsql {
UPDATE test1 SET x=11 WHERE f1=1025
}} msg]
lappend v $msg
} {1 {no such column: x}}
do_test update-9.2 {
set v [catch {execsql {
UPDATE test1 SET f1=x(11) WHERE f1=1025
}} msg]
lappend v $msg
} {1 {no such function: x}}
do_test update-9.3 {
set v [catch {execsql {
UPDATE test1 SET f1=11 WHERE x=1025
}} msg]
lappend v $msg
} {1 {no such column: x}}
do_test update-9.4 {
set v [catch {execsql {
UPDATE test1 SET f1=11 WHERE x(f1)=1025
}} msg]
lappend v $msg
} {1 {no such function: x}}
# Try doing updates on a unique column where the value does not
# really change.
#
do_test update-10.1 {
execsql {
DROP TABLE test1;
CREATE TABLE t1(
a integer primary key,
b UNIQUE,
c, d,
e, f,
UNIQUE(c,d)
);
INSERT INTO t1 VALUES(1,2,3,4,5,6);
INSERT INTO t1 VALUES(2,3,4,4,6,7);
SELECT * FROM t1
}
} {1 2 3 4 5 6 2 3 4 4 6 7}
do_test update-10.2 {
catchsql {
UPDATE t1 SET a=1, e=9 WHERE f=6;
SELECT * FROM t1;
}
} {0 {1 2 3 4 9 6 2 3 4 4 6 7}}
do_test update-10.3 {
catchsql {
UPDATE t1 SET a=1, e=10 WHERE f=7;
SELECT * FROM t1;
}
} {1 {UNIQUE constraint failed: t1.a}}
do_test update-10.4 {
catchsql {
SELECT * FROM t1;
}
} {0 {1 2 3 4 9 6 2 3 4 4 6 7}}
do_test update-10.5 {
catchsql {
UPDATE t1 SET b=2, e=11 WHERE f=6;
SELECT * FROM t1;
}
} {0 {1 2 3 4 11 6 2 3 4 4 6 7}}
do_test update-10.6 {
catchsql {
UPDATE t1 SET b=2, e=12 WHERE f=7;
SELECT * FROM t1;
}
} {1 {UNIQUE constraint failed: t1.b}}
do_test update-10.7 {
catchsql {
SELECT * FROM t1;
}
} {0 {1 2 3 4 11 6 2 3 4 4 6 7}}
do_test update-10.8 {
catchsql {
UPDATE t1 SET c=3, d=4, e=13 WHERE f=6;
SELECT * FROM t1;
}
} {0 {1 2 3 4 13 6 2 3 4 4 6 7}}
do_test update-10.9 {
catchsql {
UPDATE t1 SET c=3, d=4, e=14 WHERE f=7;
SELECT * FROM t1;
}
} {1 {UNIQUE constraint failed: t1.c, t1.d}}
do_test update-10.10 {
catchsql {
SELECT * FROM t1;
}
} {0 {1 2 3 4 13 6 2 3 4 4 6 7}}
# Make sure we can handle a subquery in the where clause.
#
ifcapable subquery {
do_test update-11.1 {
execsql {
UPDATE t1 SET e=e+1 WHERE b IN (SELECT b FROM t1);
SELECT b,e FROM t1;
}
} {2 14 3 7}
do_test update-11.2 {
execsql {
UPDATE t1 SET e=e+1 WHERE a IN (SELECT a FROM t1);
SELECT a,e FROM t1;
}
} {1 15 2 8}
do_test update-11.3 {
execsql {
UPDATE t1 AS xyz SET e=e+1 WHERE xyz.a IN (SELECT a FROM t1);
SELECT a,e FROM t1;
}
} {1 16 2 9}
do_test update-11.4 {
execsql {
UPDATE t1 AS xyz SET e=e+1 WHERE EXISTS(SELECT 1 FROM t1 WHERE t1.a<xyz.a);
SELECT a,e FROM t1;
}
} {1 16 2 10}
}
integrity_check update-12.1
# Ticket 602. Updates should occur in the same order as the records
# were discovered in the WHERE clause.
#
do_test update-13.1 {
execsql {
BEGIN;
CREATE TABLE t2(a);
INSERT INTO t2 VALUES(1);
INSERT INTO t2 VALUES(2);
INSERT INTO t2 SELECT a+2 FROM t2;
INSERT INTO t2 SELECT a+4 FROM t2;
INSERT INTO t2 SELECT a+8 FROM t2;
INSERT INTO t2 SELECT a+16 FROM t2;
INSERT INTO t2 SELECT a+32 FROM t2;
INSERT INTO t2 SELECT a+64 FROM t2;
INSERT INTO t2 SELECT a+128 FROM t2;
INSERT INTO t2 SELECT a+256 FROM t2;
INSERT INTO t2 SELECT a+512 FROM t2;
INSERT INTO t2 SELECT a+1024 FROM t2;
COMMIT;
SELECT count(*) FROM t2;
}
} {2048}
do_test update-13.2 {
execsql {
SELECT count(*) FROM t2 WHERE a=rowid;
}
} {2048}
do_test update-13.3 {
execsql {
UPDATE t2 SET rowid=rowid-1;
SELECT count(*) FROM t2 WHERE a=rowid+1;
}
} {2048}
do_test update-13.3 {
execsql {
UPDATE t2 SET rowid=rowid+10000;
UPDATE t2 SET rowid=rowid-9999;
SELECT count(*) FROM t2 WHERE a=rowid;
}
} {2048}
do_test update-13.4 {
execsql {
BEGIN;
INSERT INTO t2 SELECT a+2048 FROM t2;
INSERT INTO t2 SELECT a+4096 FROM t2;
INSERT INTO t2 SELECT a+8192 FROM t2;
SELECT count(*) FROM t2 WHERE a=rowid;
COMMIT;
}
} 16384
do_test update-13.5 {
execsql {
UPDATE t2 SET rowid=rowid-1;
SELECT count(*) FROM t2 WHERE a=rowid+1;
}
} 16384
integrity_check update-13.6
ifcapable {trigger} {
# Test for proper detection of malformed WHEN clauses on UPDATE triggers.
#
do_test update-14.1 {
execsql {
CREATE TABLE t3(a,b,c);
CREATE TRIGGER t3r1 BEFORE UPDATE on t3 WHEN nosuchcol BEGIN
SELECT 'illegal WHEN clause';
END;
}
} {}
do_test update-14.2 {
catchsql {
UPDATE t3 SET a=1;
}
} {1 {no such column: nosuchcol}}
do_test update-14.3 {
execsql {
CREATE TABLE t4(a,b,c);
CREATE TRIGGER t4r1 AFTER UPDATE on t4 WHEN nosuchcol BEGIN
SELECT 'illegal WHEN clause';
END;
}
} {}
do_test update-14.4 {
catchsql {
UPDATE t4 SET a=1;
}
} {1 {no such column: nosuchcol}}
} ;# ifcapable {trigger}
# Ticket [https://www.sqlite.org/src/tktview/43107840f1c02] on 2014-10-29
# An assertion fault on UPDATE
#
ifcapable altertable {
do_execsql_test update-15.1 {
CREATE TABLE t15(a INTEGER PRIMARY KEY, b);
INSERT INTO t15(a,b) VALUES(10,'abc'),(20,'def'),(30,'ghi');
ALTER TABLE t15 ADD COLUMN c;
CREATE INDEX t15c ON t15(c);
INSERT INTO t15(a,b)
VALUES(5,'zyx'),(15,'wvu'),(25,'tsr'),(35,'qpo');
UPDATE t15 SET c=printf('y%d',a) WHERE c IS NULL;
SELECT a,b,c,'|' FROM t15 ORDER BY a;
} {5 zyx y5 | 10 abc y10 | 15 wvu y15 | 20 def y20 | 25 tsr y25 | 30 ghi y30 | 35 qpo y35 |}
}
# Unreleased bug in UPDATE caused by the UPSERT changes.
# Found by OSSFuzz as soon as the UPSERT changes landed on trunk.
# Never released into the wild. 2018-04-19.
#
do_execsql_test update-16.1 {
CREATE TABLE t16(a INTEGER PRIMARY KEY ON CONFLICT REPLACE, b UNIQUE);
INSERT INTO t16(a,b) VALUES(1,2),(3,4),(5,6);
UPDATE t16 SET a=a;
SELECT * FROM t16 ORDER BY +a;
} {1 2 3 4 5 6}
# 2019-12-09 gramfuzz find
# If a partial index that does not reference any column of its table (which is you
# must admit is a very strange index, but one that is allowed) is used by an UPDATE
# statement, void the use of OP_DeferredSeek on the main loop, as the seek will not
# be resolved prior to the OP_Delete.
#
do_execsql_test update-17.10 {
DROP TABLE IF EXISTS t1;
CREATE TABLE t1(x,y);
INSERT INTO t1(x) VALUES(1);
CREATE INDEX t1x1 ON t1(1) WHERE 3;
UPDATE t1 SET x=2, y=3 WHERE 3;
SELECT * FROM t1;
} {2 3}
# 2019-12-22 ticket 5ad2aa6921faa1ee
# Make a hard-copy of values that need to be run through OP_RealAffinity
# rather than a soft-copy. This is not strictly necessary, but it avoids
# a memory-accounting assert().
#
reset_db
do_execsql_test update-18.10 {
PRAGMA encoding = 'UTF16';
CREATE TABLE t0(c0 REAL, c1);
INSERT INTO t0(c0,c1) VALUES('xyz',11),('uvw',22);
CREATE INDEX i0 ON t0(c1) WHERE c0 GLOB 3;
CREATE INDEX i1 ON t0(c0,c1) WHERE typeof(c0)='text' AND typeof(c1)='integer';
UPDATE t0 SET c1=345;
SELECT * FROM t0;
} {xyz 345 uvw 345}
# 2019-12-22 ticket c62c5e58524b204d
# This is really the same underlying problem as 5ad2aa6921faa1ee
#
reset_db
do_execsql_test update-18.20 {
PRAGMA encoding = 'utf16';
CREATE TABLE t0(c0 TEXT);
CREATE INDEX i0 ON t0(0 LIKE COALESCE(c0, 0));
INSERT INTO t0(c0) VALUES (0), (0);
SELECT * FROM t0;
} {0 0}
# 2019-12-28 assertion fault reported by Yongheng
# Similar to ticket ec8abb025e78f40c
# An UPDATE was reaching the OP_Delete after running OP_DeferredSeek
# without ever hitting an OP_Column. The enhanced solution is to
# fix OP_Delete so that it can do the seek itself.
#
reset_db
do_execsql_test update-19.10 {
CREATE TABLE t1(
a TEXT,
b INTEGER PRIMARY KEY UNIQUE
);
INSERT INTO t1 VALUES(1,2);
UPDATE t1 SET a = quote(b) WHERE b>=2;
SELECT * FROM t1;
} {2 2}
# 2019-12-29 ticket https://www.sqlite.org/src/info/314cc133e5ada126
# REPLACE conflict resolution during an UPDATE causes a DELETE trigger
# to fire. If that DELETE trigger subsequently modifies the row
# being updated, bad things can happen. Prevent this by prohibiting
# triggers from making changes to the table being updated while doing
# REPLACE conflict resolution on the UPDATE.
#
# See also tickets:
# https://www.sqlite.org/src/info/c1e19e12046d23fe 2019-10-25
# https://www.sqlite.org/src/info/a8a4847a2d96f5de 2019-10-16
#
reset_db
do_execsql_test update-20.10 {
PRAGMA recursive_triggers = true;
CREATE TABLE t1(a UNIQUE ON CONFLICT REPLACE, b);
INSERT INTO t1(a,b) VALUES(4,12),(9,13);
CREATE INDEX i0 ON t1(b);
CREATE TRIGGER tr0 DELETE ON t1 BEGIN
UPDATE t1 SET b = a;
END;
PRAGMA integrity_check;
} {ok}
do_catchsql_test update-20.20 {
UPDATE t1 SET a=0;
} {1 {constraint failed}}
do_execsql_test update-20.30 {
PRAGMA integrity_check;
} {ok}
# 2023-03-16 https://sqlite.org/forum/forumpost/0007d1fdb1
# A subquery in the WHERE clause of an UPDATE and behind a
# short-circuit evaluation caused problems because multi-row
# single-pass was selected.
#
# Similar problem for DELETE tested by delete-12.0.
# https://sqlite.org/src/info/73f0036f045bf371
#
reset_db
do_execsql_test update-21.1 {
CREATE TABLE t1 (vkey INTEGER, c5 INTEGER);
INSERT INTO t1 VALUES(3,NULL),(6,-54);
}
db null NULL
do_execsql_test update-21.2 {
BEGIN;
UPDATE t1 SET vkey = 100 WHERE c5 is null;
SELECT * FROM t1 ORDER BY vkey, c5;
ROLLBACK;
} {6 -54 100 NULL}
do_execsql_test update-21.3 {
BEGIN;
UPDATE t1 SET vkey = 100 WHERE NOT (-10*(select min(vkey) from t1) >= c5);
SELECT * FROM t1 ORDER BY vkey, c5;
ROLLBACK;
} {3 NULL 6 -54}
do_execsql_test update-21.4 {
BEGIN;
UPDATE t1 SET vkey = 100 WHERE c5 is null OR NOT (-10*(select min(vkey) from t1) >= c5);
SELECT * FROM t1 ORDER BY vkey, c5;
ROLLBACK;
} {6 -54 100 NULL}
# Follow-up on 2023-07-31 (forum post https://sqlite.org/forum/forumpost/8ab195fd44e75ed0):
# Only disable one-pass if the subquery is in the WHERE clause. The SET expressions
# do not count.
do_execsql_test update-21.11 {
DROP TABLE t1;
CREATE TABLE t1(a INTEGER PRIMARY KEY, b INT);
CREATE TABLE t2(d INT);
}
do_eqp_test update-21.12 {
WITH t3(x,y) AS (SELECT d, row_number()OVER() FROM t2)
UPDATE t1 SET b=(SELECT y FROM t3 WHERE t1.a=t3.x);
} {
QUERY PLAN
|--SCAN t1
`--CORRELATED SCALAR SUBQUERY xxxxxx
|--CO-ROUTINE t3
| |--CO-ROUTINE (subquery-xxxxxx)
| | `--SCAN t2
| `--SCAN (subquery-xxxxxx)
|--BLOOM FILTER ON t3 (x=?)
`--SEARCH t3 USING AUTOMATIC COVERING INDEX (x=?)
}
finish_test