xref: /sqlite-3.40.0/test/upsert2.test (revision 6bcd5857)
15015c9b5Sdrh# 2018-04-17
25015c9b5Sdrh#
35015c9b5Sdrh# The author disclaims copyright to this source code.  In place of
45015c9b5Sdrh# a legal notice, here is a blessing:
55015c9b5Sdrh#
65015c9b5Sdrh#    May you do good and not evil.
75015c9b5Sdrh#    May you find forgiveness for yourself and forgive others.
85015c9b5Sdrh#    May you share freely, never taking more than you give.
95015c9b5Sdrh#
105015c9b5Sdrh#***********************************************************************
115015c9b5Sdrh#
125015c9b5Sdrh# Test cases for UPSERT
135015c9b5Sdrh
145015c9b5Sdrhset testdir [file dirname $argv0]
155015c9b5Sdrhsource $testdir/tester.tcl
165015c9b5Sdrhset testprefix zipfile
175015c9b5Sdrh
185015c9b5Sdrhdo_execsql_test upsert2-100 {
195015c9b5Sdrh  CREATE TABLE t1(a INTEGER PRIMARY KEY, b int, c DEFAULT 0);
205015c9b5Sdrh  INSERT INTO t1(a,b) VALUES(1,2),(3,4);
215015c9b5Sdrh  INSERT INTO t1(a,b) VALUES(1,8),(2,11),(3,1)
225015c9b5Sdrh    ON CONFLICT(a) DO UPDATE SET b=excluded.b, c=c+1 WHERE t1.b<excluded.b;
235015c9b5Sdrh  SELECT *, 'x' FROM t1 ORDER BY a;
245015c9b5Sdrh} {1 8 1 x 2 11 0 x 3 4 0 x}
255015c9b5Sdrhdo_execsql_test upsert2-110 {
265015c9b5Sdrh  DROP TABLE t1;
275015c9b5Sdrh  CREATE TABLE t1(a INT PRIMARY KEY, b int, c DEFAULT 0) WITHOUT ROWID;
285015c9b5Sdrh  INSERT INTO t1(a,b) VALUES(1,2),(3,4);
295015c9b5Sdrh  INSERT INTO t1(a,b) VALUES(1,8),(2,11),(3,1)
305015c9b5Sdrh    ON CONFLICT(a) DO UPDATE SET b=excluded.b, c=c+1 WHERE t1.b<excluded.b;
315015c9b5Sdrh  SELECT *, 'x' FROM t1 ORDER BY a;
325015c9b5Sdrh} {1 8 1 x 2 11 0 x 3 4 0 x}
335015c9b5Sdrh
345015c9b5Sdrhdo_execsql_test upsert2-200 {
355015c9b5Sdrh  DROP TABLE t1;
365015c9b5Sdrh  CREATE TABLE t1(a INTEGER PRIMARY KEY, b int, c DEFAULT 0);
375015c9b5Sdrh  INSERT INTO t1(a,b) VALUES(1,2),(3,4);
385015c9b5Sdrh  WITH nx(a,b) AS (VALUES(1,8),(2,11),(3,1),(2,15),(1,4),(1,99))
395015c9b5Sdrh  INSERT INTO t1(a,b) SELECT a, b FROM nx WHERE true
405015c9b5Sdrh    ON CONFLICT(a) DO UPDATE SET b=excluded.b, c=c+1 WHERE t1.b<excluded.b;
415015c9b5Sdrh  SELECT *, 'x' FROM t1 ORDER BY a;
425015c9b5Sdrh} {1 99 2 x 2 15 1 x 3 4 0 x}
435015c9b5Sdrhdo_execsql_test upsert2-201 {
445015c9b5Sdrh  DELETE FROM t1;
455015c9b5Sdrh  INSERT INTO t1(a,b) VALUES(1,2),(3,4);
465015c9b5Sdrh  WITH nx(a,b) AS (VALUES(1,8),(2,11),(3,1),(2,15),(1,4),(1,99))
475e3a6ebfSdrh  INSERT INTO main.t1 AS t2(a,b) SELECT a, b FROM nx WHERE true
485015c9b5Sdrh    ON CONFLICT(a) DO UPDATE SET b=excluded.b, c=t2.c+1 WHERE t2.b<excluded.b;
495015c9b5Sdrh  SELECT *, 'x' FROM t1 ORDER BY a;
505015c9b5Sdrh} {1 99 2 x 2 15 1 x 3 4 0 x}
515015c9b5Sdrhdo_catchsql_test upsert2-202 {
525015c9b5Sdrh  WITH nx(a,b) AS (VALUES(1,8),(2,11),(3,1),(2,15),(1,4),(1,99))
535e3a6ebfSdrh  INSERT INTO t1 AS t2(a,b) SELECT a, b FROM nx WHERE true
545015c9b5Sdrh    ON CONFLICT(a) DO UPDATE SET b=excluded.b, c=t1.c+1 WHERE t1.b<excluded.b;
555015c9b5Sdrh} {1 {no such column: t1.c}}
565015c9b5Sdrhdo_execsql_test upsert2-210 {
575015c9b5Sdrh  DROP TABLE t1;
585015c9b5Sdrh  CREATE TABLE t1(a INT PRIMARY KEY, b int, c DEFAULT 0) WITHOUT ROWID;
595015c9b5Sdrh  INSERT INTO t1(a,b) VALUES(1,2),(3,4);
605015c9b5Sdrh  WITH nx(a,b) AS (VALUES(1,8),(2,11),(3,1),(2,15),(1,4),(1,99))
615015c9b5Sdrh  INSERT INTO t1(a,b) SELECT a, b FROM nx WHERE true
625015c9b5Sdrh    ON CONFLICT(a) DO UPDATE SET b=excluded.b, c=c+1 WHERE t1.b<excluded.b;
635015c9b5Sdrh  SELECT *, 'x' FROM t1 ORDER BY a;
645015c9b5Sdrh} {1 99 2 x 2 15 1 x 3 4 0 x}
655015c9b5Sdrh
665015c9b5Sdrh# On an ON CONFLICT DO UPDATE, the before-insert, before-update, and
675015c9b5Sdrh# after-update triggers fire.
685015c9b5Sdrh#
695015c9b5Sdrhdo_execsql_test upsert2-300 {
705015c9b5Sdrh  DROP TABLE t1;
715015c9b5Sdrh  CREATE TABLE t1(a INTEGER PRIMARY KEY, b int, c DEFAULT 0);
725015c9b5Sdrh  CREATE TABLE record(x TEXT, y TEXT);
735015c9b5Sdrh  CREATE TRIGGER r1 BEFORE INSERT ON t1 BEGIN
745015c9b5Sdrh    INSERT INTO record(x,y)
75*6bcd5857Sdrh        VALUES('before-insert',format('%d,%d,%d',new.a,new.b,new.c));
765015c9b5Sdrh  END;
775015c9b5Sdrh  CREATE TRIGGER r2 AFTER INSERT ON t1 BEGIN
785015c9b5Sdrh    INSERT INTO record(x,y)
795015c9b5Sdrh        VALUES('after-insert',printf('%d,%d,%d',new.a,new.b,new.c));
805015c9b5Sdrh  END;
815015c9b5Sdrh  CREATE TRIGGER r3 BEFORE UPDATE ON t1 BEGIN
825015c9b5Sdrh    INSERT INTO record(x,y)
83*6bcd5857Sdrh        VALUES('before-update',format('%d,%d,%d/%d,%d,%d',
845015c9b5Sdrh                                      old.a,old.b,old.c,new.a,new.b,new.c));
855015c9b5Sdrh  END;
865015c9b5Sdrh  CREATE TRIGGER r4 AFTER UPDATE ON t1 BEGIN
875015c9b5Sdrh    INSERT INTO record(x,y)
885015c9b5Sdrh        VALUES('after-update',printf('%d,%d,%d/%d,%d,%d',
895015c9b5Sdrh                                      old.a,old.b,old.c,new.a,new.b,new.c));
905015c9b5Sdrh  END;
915015c9b5Sdrh  INSERT INTO t1(a,b) VALUES(1,2);
925015c9b5Sdrh  DELETE FROM record;
935015c9b5Sdrh  INSERT INTO t1(a,b) VALUES(1,2)
945015c9b5Sdrh    ON CONFLICT(a) DO UPDATE SET c=t1.c+1;
955015c9b5Sdrh  SELECT * FROM record
965015c9b5Sdrh} {before-insert 1,2,0 before-update 1,2,0/1,2,1 after-update 1,2,0/1,2,1}
975015c9b5Sdrh
985015c9b5Sdrh# On an ON CONFLICT DO NOTHING, only the before-insert trigger fires.
995015c9b5Sdrh#
1005015c9b5Sdrhdo_execsql_test upsert2-310 {
1015015c9b5Sdrh  DELETE FROM record;
1025015c9b5Sdrh  INSERT INTO t1(a,b) VALUES(1,2) ON CONFLICT DO NOTHING;
1035015c9b5Sdrh  SELECT * FROM record;
1045015c9b5Sdrh} {before-insert 1,2,0}
1055015c9b5Sdrh
1065015c9b5Sdrh# With ON CONFLICT DO UPDATE and a failed WHERE, only the before-insert
1075015c9b5Sdrh# trigger fires.
1085015c9b5Sdrh#
1095015c9b5Sdrhdo_execsql_test upsert2-320 {
1105015c9b5Sdrh  DELETE FROM record;
1115015c9b5Sdrh  INSERT INTO t1(a,b) VALUES(1,2)
1125015c9b5Sdrh    ON CONFLICT(a) DO UPDATE SET c=c+1 WHERE c<0;
1135015c9b5Sdrh  SELECT * FROM record;
1145015c9b5Sdrh} {before-insert 1,2,0}
1155015c9b5Sdrhdo_execsql_test upsert2-321 {
1165015c9b5Sdrh  SELECT * FROM t1;
1175015c9b5Sdrh} {1 2 1}
1185015c9b5Sdrh
1195015c9b5Sdrh# Trigger tests repeated for a WITHOUT ROWID table.
1205015c9b5Sdrh#
1215015c9b5Sdrhdo_execsql_test upsert2-400 {
1225015c9b5Sdrh  DROP TABLE t1;
1235015c9b5Sdrh  CREATE TABLE t1(a INT PRIMARY KEY, b int, c DEFAULT 0) WITHOUT ROWID;
1245015c9b5Sdrh  CREATE TRIGGER r1 BEFORE INSERT ON t1 BEGIN
1255015c9b5Sdrh    INSERT INTO record(x,y)
126*6bcd5857Sdrh        VALUES('before-insert',format('%d,%d,%d',new.a,new.b,new.c));
1275015c9b5Sdrh  END;
1285015c9b5Sdrh  CREATE TRIGGER r2 AFTER INSERT ON t1 BEGIN
1295015c9b5Sdrh    INSERT INTO record(x,y)
1305015c9b5Sdrh        VALUES('after-insert',printf('%d,%d,%d',new.a,new.b,new.c));
1315015c9b5Sdrh  END;
1325015c9b5Sdrh  CREATE TRIGGER r3 BEFORE UPDATE ON t1 BEGIN
1335015c9b5Sdrh    INSERT INTO record(x,y)
134*6bcd5857Sdrh        VALUES('before-update',format('%d,%d,%d/%d,%d,%d',
1355015c9b5Sdrh                                      old.a,old.b,old.c,new.a,new.b,new.c));
1365015c9b5Sdrh  END;
1375015c9b5Sdrh  CREATE TRIGGER r4 AFTER UPDATE ON t1 BEGIN
1385015c9b5Sdrh    INSERT INTO record(x,y)
1395015c9b5Sdrh        VALUES('after-update',printf('%d,%d,%d/%d,%d,%d',
1405015c9b5Sdrh                                      old.a,old.b,old.c,new.a,new.b,new.c));
1415015c9b5Sdrh  END;
1425015c9b5Sdrh  INSERT INTO t1(a,b) VALUES(1,2);
1435015c9b5Sdrh  DELETE FROM record;
1445015c9b5Sdrh  INSERT INTO t1(a,b) VALUES(1,2)
1455015c9b5Sdrh    ON CONFLICT(a) DO UPDATE SET c=t1.c+1;
1465015c9b5Sdrh  SELECT * FROM record
1475015c9b5Sdrh} {before-insert 1,2,0 before-update 1,2,0/1,2,1 after-update 1,2,0/1,2,1}
1485015c9b5Sdrh
1495015c9b5Sdrh# On an ON CONFLICT DO NOTHING, only the before-insert trigger fires.
1505015c9b5Sdrh#
1515015c9b5Sdrhdo_execsql_test upsert2-410 {
1525015c9b5Sdrh  DELETE FROM record;
1535015c9b5Sdrh  INSERT INTO t1(a,b) VALUES(1,2) ON CONFLICT DO NOTHING;
1545015c9b5Sdrh  SELECT * FROM record;
1555015c9b5Sdrh} {before-insert 1,2,0}
1565015c9b5Sdrh
1575015c9b5Sdrh# With ON CONFLICT DO UPDATE and a failed WHERE, only the before-insert
1585015c9b5Sdrh# trigger fires.
1595015c9b5Sdrh#
1605015c9b5Sdrhdo_execsql_test upsert2-420 {
1615015c9b5Sdrh  DELETE FROM record;
1625015c9b5Sdrh  INSERT INTO t1(a,b) VALUES(1,2)
1635015c9b5Sdrh    ON CONFLICT(a) DO UPDATE SET c=c+1 WHERE c<0;
1645015c9b5Sdrh  SELECT * FROM record;
1655015c9b5Sdrh} {before-insert 1,2,0}
1665015c9b5Sdrhdo_execsql_test upsert2-421 {
1675015c9b5Sdrh  SELECT * FROM t1;
1685015c9b5Sdrh} {1 2 1}
1695015c9b5Sdrh
1705015c9b5Sdrhfinish_test
171