xref: /sqlite-3.40.0/test/upsert1.test (revision 66306d86)
1788d55aaSdrh# 2018-04-12
2788d55aaSdrh#
3788d55aaSdrh# The author disclaims copyright to this source code.  In place of
4788d55aaSdrh# a legal notice, here is a blessing:
5788d55aaSdrh#
6788d55aaSdrh#    May you do good and not evil.
7788d55aaSdrh#    May you find forgiveness for yourself and forgive others.
8788d55aaSdrh#    May you share freely, never taking more than you give.
9788d55aaSdrh#
10788d55aaSdrh#***********************************************************************
11788d55aaSdrh#
12788d55aaSdrh# Test cases for UPSERT
13788d55aaSdrh
14788d55aaSdrhset testdir [file dirname $argv0]
15788d55aaSdrhsource $testdir/tester.tcl
16788d55aaSdrhset testprefix zipfile
17788d55aaSdrh
18788d55aaSdrhdo_execsql_test upsert1-100 {
19e9c2e772Sdrh  CREATE TABLE t1(a INTEGER PRIMARY KEY, b TEXT, c DEFAULT 0);
20e9c2e772Sdrh  CREATE UNIQUE INDEX t1x1 ON t1(b);
21788d55aaSdrh  INSERT INTO t1(a,b) VALUES(1,2) ON CONFLICT DO NOTHING;
22c8a0c90bSdrh  INSERT INTO t1(a,b) VALUES(1,99),(99,2) ON CONFLICT DO NOTHING;
23788d55aaSdrh  SELECT * FROM t1;
24e9c2e772Sdrh} {1 2 0}
25788d55aaSdrhdo_execsql_test upsert1-101 {
26788d55aaSdrh  DELETE FROM t1;
27788d55aaSdrh  INSERT INTO t1(a,b) VALUES(2,3) ON CONFLICT(a) DO NOTHING;
28c8a0c90bSdrh  INSERT INTO t1(a,b) VALUES(2,99) ON CONFLICT(a) DO NOTHING;
29788d55aaSdrh  SELECT * FROM t1;
30e9c2e772Sdrh} {2 3 0}
31788d55aaSdrhdo_execsql_test upsert1-102 {
32788d55aaSdrh  DELETE FROM t1;
33e9c2e772Sdrh  INSERT INTO t1(a,b) VALUES(3,4) ON CONFLICT(b) DO NOTHING;
34c8a0c90bSdrh  INSERT INTO t1(a,b) VALUES(99,4) ON CONFLICT(b) DO NOTHING;
35788d55aaSdrh  SELECT * FROM t1;
36e9c2e772Sdrh} {3 4 0}
37788d55aaSdrhdo_catchsql_test upsert1-110 {
38e9c2e772Sdrh  INSERT INTO t1(a,b) VALUES(5,6) ON CONFLICT(x) DO NOTHING;
39e9c2e772Sdrh  SELECT * FROM t1;
40e9c2e772Sdrh} {1 {no such column: x}}
41788d55aaSdrhdo_catchsql_test upsert1-120 {
42e9c2e772Sdrh  INSERT INTO t1(a,b) VALUES(5,6) ON CONFLICT(c) DO NOTHING;
43e9c2e772Sdrh  SELECT * FROM t1;
44e9c2e772Sdrh} {1 {ON CONFLICT clause does not match any PRIMARY KEY or UNIQUE constraint}}
453b45d8bfSdrhbreakpoint
46e9c2e772Sdrhdo_catchsql_test upsert1-130 {
47e9c2e772Sdrh  INSERT INTO t1(a,b) VALUES(5,6) ON CONFLICT(b COLLATE nocase) DO NOTHING;
48e9c2e772Sdrh  SELECT * FROM t1;
49e9c2e772Sdrh} {1 {ON CONFLICT clause does not match any PRIMARY KEY or UNIQUE constraint}}
50d5af5420Sdrhdo_execsql_test upsert1-140 {
51d5af5420Sdrh  DELETE FROM t1;
52d5af5420Sdrh  INSERT INTO t1(a,b) VALUES(5,6) ON CONFLICT(b COLLATE binary) DO NOTHING;
53d5af5420Sdrh  SELECT * FROM t1;
54d5af5420Sdrh} {5 6 0}
55e9c2e772Sdrh
56e9c2e772Sdrhdo_catchsql_test upsert1-200 {
57c8a0c90bSdrh  DROP TABLE t1;
58c8a0c90bSdrh  CREATE TABLE t1(a INTEGER PRIMARY KEY, b INT, c DEFAULT 0);
59c8a0c90bSdrh  CREATE UNIQUE INDEX t1x1 ON t1(a+b);
60c8a0c90bSdrh  INSERT INTO t1(a,b) VALUES(7,8) ON CONFLICT(a+b) DO NOTHING;
61c8a0c90bSdrh  INSERT INTO t1(a,b) VALUES(8,7),(9,6) ON CONFLICT(a+b) DO NOTHING;
62e9c2e772Sdrh  SELECT * FROM t1;
63c8a0c90bSdrh} {0 {7 8 0}}
64c8a0c90bSdrhdo_catchsql_test upsert1-201 {
65c8a0c90bSdrh  INSERT INTO t1(a,b) VALUES(8,7),(9,6) ON CONFLICT(a) DO NOTHING;
66c8a0c90bSdrh} {1 {UNIQUE constraint failed: index 't1x1'}}
673b45d8bfSdrhdo_catchsql_test upsert1-210 {
683b45d8bfSdrh  DELETE FROM t1;
69c8a0c90bSdrh  INSERT INTO t1(a,b) VALUES(9,10) ON CONFLICT(a+(+b)) DO NOTHING;
703b45d8bfSdrh  SELECT * FROM t1;
713b45d8bfSdrh} {1 {ON CONFLICT clause does not match any PRIMARY KEY or UNIQUE constraint}}
723b45d8bfSdrh
73d5af5420Sdrhdo_catchsql_test upsert1-300 {
74d5af5420Sdrh  DROP INDEX t1x1;
75d5af5420Sdrh  DELETE FROM t1;
76d5af5420Sdrh  CREATE UNIQUE INDEX t1x1 ON t1(b) WHERE b>10;
77c8a0c90bSdrh  INSERT INTO t1(a,b) VALUES(1,2),(3,2) ON CONFLICT(b) DO NOTHING;
78d5af5420Sdrh  SELECT * FROM t1;
79d5af5420Sdrh} {1 {ON CONFLICT clause does not match any PRIMARY KEY or UNIQUE constraint}}
80d5af5420Sdrhdo_catchsql_test upsert1-310 {
81d5af5420Sdrh  DELETE FROM t1;
82c8a0c90bSdrh  INSERT INTO t1(a,b) VALUES(1,2),(3,2) ON CONFLICT(b) WHERE b!=10 DO NOTHING;
83d5af5420Sdrh  SELECT * FROM t1;
84d5af5420Sdrh} {1 {ON CONFLICT clause does not match any PRIMARY KEY or UNIQUE constraint}}
85d5af5420Sdrhdo_execsql_test upsert1-320 {
86d5af5420Sdrh  DELETE FROM t1;
87c8a0c90bSdrh  INSERT INTO t1(a,b) VALUES(1,2),(3,2),(4,20),(5,20)
88c8a0c90bSdrh         ON CONFLICT(b) WHERE b>10 DO NOTHING;
89c8a0c90bSdrh  SELECT *, 'x' FROM t1 ORDER BY b, a;
90c8a0c90bSdrh} {1 2 0 x 3 2 0 x 4 20 0 x}
91788d55aaSdrh
9279636913Sdrh# Upsert works with count_changes=on;
9379636913Sdrhdo_execsql_test upsert1-400 {
9479636913Sdrh  DROP TABLE IF EXISTS t2;
9579636913Sdrh  CREATE TABLE t2(a TEXT UNIQUE, b INT DEFAULT 1);
9679636913Sdrh  INSERT INTO t2(a) VALUES('one'),('two'),('three');
9779636913Sdrh  PRAGMA count_changes=ON;
9879636913Sdrh  INSERT INTO t2(a) VALUES('one'),('one'),('three'),('four')
9979636913Sdrh      ON CONFLICT(a) DO UPDATE SET b=b+1;
10079636913Sdrh} {1}
10179636913Sdrhdo_execsql_test upsert1-410 {
10279636913Sdrh  PRAGMA count_changes=OFF;
10379636913Sdrh  SELECT a, b FROM t2 ORDER BY a;
10479636913Sdrh} {four 1 one 3 three 2 two 1}
10579636913Sdrh
106f49ff6ffSdrh# Problem found by AFL prior to any release
107f49ff6ffSdrhdo_execsql_test upsert1-500 {
108f49ff6ffSdrh  DROP TABLE t1;
109f49ff6ffSdrh  CREATE TABLE t1(x INTEGER PRIMARY KEY, y INT UNIQUE);
110f49ff6ffSdrh  INSERT INTO t1(x,y) SELECT 1,2 WHERE true
111f49ff6ffSdrh    ON CONFLICT(x) DO UPDATE SET y=max(t1.y,excluded.y) AND true;
112f49ff6ffSdrh  SELECT * FROM t1;
113f49ff6ffSdrh} {1 2}
11479636913Sdrh
115222a384aSdrh# 2018-07-11
116222a384aSdrh# Ticket https://sqlite.org/src/tktview/79cad5e4b2e219dd197242e9e5f4
117222a384aSdrh# UPSERT leads to a corrupt index.
118222a384aSdrh#
119222a384aSdrhdo_execsql_test upsert1-600 {
120222a384aSdrh  DROP TABLE t1;
121222a384aSdrh  CREATE TABLE t1(b UNIQUE, a INT PRIMARY KEY) WITHOUT ROWID;
122222a384aSdrh  INSERT OR IGNORE INTO t1(a) VALUES('1') ON CONFLICT(a) DO NOTHING;
123222a384aSdrh  PRAGMA integrity_check;
124222a384aSdrh} {ok}
125222a384aSdrhdo_execsql_test upsert1-610 {
126222a384aSdrh  DELETE FROM t1;
127222a384aSdrh  INSERT OR IGNORE INTO t1(a) VALUES('1'),(1) ON CONFLICT(a) DO NOTHING;
128222a384aSdrh  PRAGMA integrity_check;
129222a384aSdrh} {ok}
130222a384aSdrh
13184304506Sdrh# 2018-08-14
13284304506Sdrh# Ticket https://www.sqlite.org/src/info/908f001483982c43
13384304506Sdrh# If there are multiple uniqueness contraints, the UPSERT should fire
13484304506Sdrh# if the one constraint it targets fails, regardless of whether or not
13584304506Sdrh# the other constraints pass or fail.  In other words, the UPSERT constraint
13684304506Sdrh# should be tested first.
13784304506Sdrh#
13884304506Sdrhdo_execsql_test upsert1-700 {
13984304506Sdrh  DROP TABLE t1;
14084304506Sdrh  CREATE TABLE t1(a INTEGER PRIMARY KEY, b INT, c INT, d INT, e INT);
14184304506Sdrh  CREATE UNIQUE INDEX t1b ON t1(b);
14284304506Sdrh  CREATE UNIQUE INDEX t1e ON t1(e);
14384304506Sdrh  INSERT INTO t1(a,b,c,d,e) VALUES(1,2,3,4,5);
14484304506Sdrh  INSERT INTO t1(a,b,c,d,e) VALUES(1,2,33,44,5)
14584304506Sdrh    ON CONFLICT(e) DO UPDATE SET c=excluded.c;
14684304506Sdrh  SELECT * FROM t1;
14784304506Sdrh} {1 2 33 4 5}
14884304506Sdrhdo_execsql_test upsert1-710 {
14984304506Sdrh  DELETE FROM t1;
15084304506Sdrh  INSERT INTO t1(a,b,c,d,e) VALUES(1,2,3,4,5);
15184304506Sdrh  INSERT INTO t1(a,b,c,d,e) VALUES(1,2,33,44,5)
15284304506Sdrh    ON CONFLICT(a) DO UPDATE SET c=excluded.c;
15384304506Sdrh  SELECT * FROM t1;
15484304506Sdrh} {1 2 33 4 5}
15584304506Sdrhdo_execsql_test upsert1-720 {
15684304506Sdrh  DELETE FROM t1;
15784304506Sdrh  INSERT INTO t1(a,b,c,d,e) VALUES(1,2,3,4,5);
15884304506Sdrh  INSERT INTO t1(a,b,c,d,e) VALUES(1,2,33,44,5)
15984304506Sdrh    ON CONFLICT(b) DO UPDATE SET c=excluded.c;
16084304506Sdrh  SELECT * FROM t1;
16184304506Sdrh} {1 2 33 4 5}
16284304506Sdrhdo_execsql_test upsert1-730 {
16384304506Sdrh  DROP TABLE t1;
16484304506Sdrh  CREATE TABLE t1(a INT, b INT, c INT, d INT, e INT);
16584304506Sdrh  CREATE UNIQUE INDEX t1a ON t1(a);
16684304506Sdrh  CREATE UNIQUE INDEX t1b ON t1(b);
16784304506Sdrh  CREATE UNIQUE INDEX t1e ON t1(e);
16884304506Sdrh  INSERT INTO t1(a,b,c,d,e) VALUES(1,2,3,4,5);
16984304506Sdrh  INSERT INTO t1(a,b,c,d,e) VALUES(1,2,33,44,5)
17084304506Sdrh    ON CONFLICT(e) DO UPDATE SET c=excluded.c;
17184304506Sdrh  SELECT * FROM t1;
17284304506Sdrh} {1 2 33 4 5}
17384304506Sdrhdo_execsql_test upsert1-740 {
17484304506Sdrh  DELETE FROM t1;
17584304506Sdrh  INSERT INTO t1(a,b,c,d,e) VALUES(1,2,3,4,5);
17684304506Sdrh  INSERT INTO t1(a,b,c,d,e) VALUES(1,2,33,44,5)
17784304506Sdrh    ON CONFLICT(a) DO UPDATE SET c=excluded.c;
17884304506Sdrh  SELECT * FROM t1;
17984304506Sdrh} {1 2 33 4 5}
18084304506Sdrhdo_execsql_test upsert1-750 {
18184304506Sdrh  DELETE FROM t1;
18284304506Sdrh  INSERT INTO t1(a,b,c,d,e) VALUES(1,2,3,4,5);
18384304506Sdrh  INSERT INTO t1(a,b,c,d,e) VALUES(1,2,33,44,5)
18484304506Sdrh    ON CONFLICT(b) DO UPDATE SET c=excluded.c;
18584304506Sdrh  SELECT * FROM t1;
18684304506Sdrh} {1 2 33 4 5}
18784304506Sdrhdo_execsql_test upsert1-760 {
18884304506Sdrh  DROP TABLE t1;
18984304506Sdrh  CREATE TABLE t1(a INT PRIMARY KEY, b INT, c INT, d INT, e INT) WITHOUT ROWID;
19084304506Sdrh  CREATE UNIQUE INDEX t1a ON t1(a);
19184304506Sdrh  CREATE UNIQUE INDEX t1b ON t1(b);
19284304506Sdrh  CREATE UNIQUE INDEX t1e ON t1(e);
19384304506Sdrh  INSERT INTO t1(a,b,c,d,e) VALUES(1,2,3,4,5);
19484304506Sdrh  INSERT INTO t1(a,b,c,d,e) VALUES(1,2,33,44,5)
19584304506Sdrh    ON CONFLICT(e) DO UPDATE SET c=excluded.c;
19684304506Sdrh  SELECT * FROM t1;
19784304506Sdrh} {1 2 33 4 5}
19884304506Sdrhdo_execsql_test upsert1-770 {
19984304506Sdrh  DELETE FROM t1;
20084304506Sdrh  INSERT INTO t1(a,b,c,d,e) VALUES(1,2,3,4,5);
20184304506Sdrh  INSERT INTO t1(a,b,c,d,e) VALUES(1,2,33,44,5)
20284304506Sdrh    ON CONFLICT(a) DO UPDATE SET c=excluded.c;
20384304506Sdrh  SELECT * FROM t1;
20484304506Sdrh} {1 2 33 4 5}
20584304506Sdrhdo_execsql_test upsert1-780 {
20684304506Sdrh  DELETE FROM t1;
20784304506Sdrh  INSERT INTO t1(a,b,c,d,e) VALUES(1,2,3,4,5);
20884304506Sdrh  INSERT INTO t1(a,b,c,d,e) VALUES(1,2,33,44,5)
20984304506Sdrh    ON CONFLICT(b) DO UPDATE SET c=excluded.c;
21084304506Sdrh  SELECT * FROM t1;
21184304506Sdrh} {1 2 33 4 5}
21284304506Sdrh
213a7ce167eSdrh# 2019-08-30 ticket https://sqlite.org/src/info/5a3dba8104421320
214a7ce167eSdrhdo_execsql_test upsert1-800 {
215a7ce167eSdrh  DROP TABLE IF EXISTS t0;
216a7ce167eSdrh  CREATE TABLE t0(c0 REAL UNIQUE, c1);
217a7ce167eSdrh  CREATE UNIQUE INDEX test800i0 ON t0(0 || c1);
218a7ce167eSdrh  INSERT INTO t0(c0, c1) VALUES (1, 2),  (2, 1);
219a7ce167eSdrh  INSERT INTO t0(c0) VALUES (1) ON CONFLICT(c0) DO UPDATE SET c1=excluded.c0;
220a7ce167eSdrh  PRAGMA integrity_check;
221a7ce167eSdrh  REINDEX;
222a7ce167eSdrh} {ok}
22384304506Sdrh
224c6b24ab1Sdrh# 2019-12-06 gramfuzz find
225c6b24ab1Sdrhsqlite3 db :memory:
226c6b24ab1Sdrhdo_execsql_test upsert1-900 {
227c6b24ab1Sdrh  CREATE VIEW t1(a) AS SELECT 1;
228c6b24ab1Sdrh  CREATE TRIGGER t1r1 INSTEAD OF INSERT ON t1 BEGIN
229c6b24ab1Sdrh     SELECT 2;
230c6b24ab1Sdrh  END;
231c6b24ab1Sdrh}
232c6b24ab1Sdrhdo_catchsql_test upsert1-910 {
233c6b24ab1Sdrh  INSERT INTO t1 VALUES(3) ON CONFLICT(x) DO NOTHING;
234c6b24ab1Sdrh} {1 {cannot UPSERT a view}}
235c6b24ab1Sdrh
236fe2a3f1dSdrh# 2019-12-26 ticket 7c13db5c3bf74001
237fe2a3f1dSdrhreset_db
238fe2a3f1dSdrhdo_catchsql_test upsert1-1000 {
239fe2a3f1dSdrh  CREATE TABLE t0(c0 PRIMARY KEY, c1, c2 UNIQUE) WITHOUT ROWID;
240fe2a3f1dSdrh  INSERT OR FAIL INTO t0(c2) VALUES (0), (NULL)
241fe2a3f1dSdrh    ON CONFLICT(c2) DO UPDATE SET c1 = c0;
242fe2a3f1dSdrh} {1 {NOT NULL constraint failed: t0.c0}}
243fe2a3f1dSdrh
244*66306d86Sdrh# 2021-12-29 forum post https://sqlite.org/forum/forumpost/06b16b8b29f8c8c3
245*66306d86Sdrh# By Jingzhou Fu. When there is both an INTEGER PRIMARY KEY ON CONFLICT REPLACE
246*66306d86Sdrh# and an upsert on a constraint other than the INTEGER PRIMARY KEY, the
247*66306d86Sdrh# constraint checking logic generates invalid bytecode which might result
248*66306d86Sdrh# in a NULL pointer dereference.
249*66306d86Sdrh#
250*66306d86Sdrhreset_db
251*66306d86Sdrhdo_execsql_test upsert1-1100 {
252*66306d86Sdrh  CREATE TABLE t1(a INTEGER PRIMARY KEY ON CONFLICT REPLACE, b UNIQUE);
253*66306d86Sdrh  INSERT INTO t1(b) VALUES(22);
254*66306d86Sdrh  INSERT INTO t1 VALUES(2,22) ON CONFLICT (b) DO NOTHING;
255*66306d86Sdrh  SELECT * FROM t1;
256*66306d86Sdrh} {1 22}
257*66306d86Sdrh
258788d55aaSdrhfinish_test
259