postgresql/src/test/regress/sql/returning.sql
Andres Freund 168d5805e4 Add support for INSERT ... ON CONFLICT DO NOTHING/UPDATE.
The newly added ON CONFLICT clause allows to specify an alternative to
raising a unique or exclusion constraint violation error when inserting.
ON CONFLICT refers to constraints that can either be specified using a
inference clause (by specifying the columns of a unique constraint) or
by naming a unique or exclusion constraint.  DO NOTHING avoids the
constraint violation, without touching the pre-existing row.  DO UPDATE
SET ... [WHERE ...] updates the pre-existing tuple, and has access to
both the tuple proposed for insertion and the existing tuple; the
optional WHERE clause can be used to prevent an update from being
executed.  The UPDATE SET and WHERE clauses have access to the tuple
proposed for insertion using the "magic" EXCLUDED alias, and to the
pre-existing tuple using the table name or its alias.

This feature is often referred to as upsert.

This is implemented using a new infrastructure called "speculative
insertion". It is an optimistic variant of regular insertion that first
does a pre-check for existing tuples and then attempts an insert.  If a
violating tuple was inserted concurrently, the speculatively inserted
tuple is deleted and a new attempt is made.  If the pre-check finds a
matching tuple the alternative DO NOTHING or DO UPDATE action is taken.
If the insertion succeeds without detecting a conflict, the tuple is
deemed inserted.

To handle the possible ambiguity between the excluded alias and a table
named excluded, and for convenience with long relation names, INSERT
INTO now can alias its target table.

Bumps catversion as stored rules change.

Author: Peter Geoghegan, with significant contributions from Heikki
    Linnakangas and Andres Freund. Testing infrastructure by Jeff Janes.
Reviewed-By: Heikki Linnakangas, Andres Freund, Robert Haas, Simon Riggs,
    Dean Rasheed, Stephen Frost and many others.
2015-05-08 05:43:10 +02:00

163 lines
3.8 KiB
SQL

--
-- Test INSERT/UPDATE/DELETE RETURNING
--
-- Simple cases
CREATE TEMP TABLE foo (f1 serial, f2 text, f3 int default 42);
INSERT INTO foo (f2,f3)
VALUES ('test', DEFAULT), ('More', 11), (upper('more'), 7+9)
RETURNING *, f1+f3 AS sum;
SELECT * FROM foo;
UPDATE foo SET f2 = lower(f2), f3 = DEFAULT RETURNING foo.*, f1+f3 AS sum13;
SELECT * FROM foo;
DELETE FROM foo WHERE f1 > 2 RETURNING f3, f2, f1, least(f1,f3);
SELECT * FROM foo;
-- Subplans and initplans in the RETURNING list
INSERT INTO foo SELECT f1+10, f2, f3+99 FROM foo
RETURNING *, f1+112 IN (SELECT q1 FROM int8_tbl) AS subplan,
EXISTS(SELECT * FROM int4_tbl) AS initplan;
UPDATE foo SET f3 = f3 * 2
WHERE f1 > 10
RETURNING *, f1+112 IN (SELECT q1 FROM int8_tbl) AS subplan,
EXISTS(SELECT * FROM int4_tbl) AS initplan;
DELETE FROM foo
WHERE f1 > 10
RETURNING *, f1+112 IN (SELECT q1 FROM int8_tbl) AS subplan,
EXISTS(SELECT * FROM int4_tbl) AS initplan;
-- Joins
UPDATE foo SET f3 = f3*2
FROM int4_tbl i
WHERE foo.f1 + 123455 = i.f1
RETURNING foo.*, i.f1 as "i.f1";
SELECT * FROM foo;
DELETE FROM foo
USING int4_tbl i
WHERE foo.f1 + 123455 = i.f1
RETURNING foo.*, i.f1 as "i.f1";
SELECT * FROM foo;
-- Check inheritance cases
CREATE TEMP TABLE foochild (fc int) INHERITS (foo);
INSERT INTO foochild VALUES(123,'child',999,-123);
ALTER TABLE foo ADD COLUMN f4 int8 DEFAULT 99;
SELECT * FROM foo;
SELECT * FROM foochild;
UPDATE foo SET f4 = f4 + f3 WHERE f4 = 99 RETURNING *;
SELECT * FROM foo;
SELECT * FROM foochild;
UPDATE foo SET f3 = f3*2
FROM int8_tbl i
WHERE foo.f1 = i.q2
RETURNING *;
SELECT * FROM foo;
SELECT * FROM foochild;
DELETE FROM foo
USING int8_tbl i
WHERE foo.f1 = i.q2
RETURNING *;
SELECT * FROM foo;
SELECT * FROM foochild;
DROP TABLE foochild;
-- Rules and views
CREATE TEMP VIEW voo AS SELECT f1, f2 FROM foo;
CREATE RULE voo_i AS ON INSERT TO voo DO INSTEAD
INSERT INTO foo VALUES(new.*, 57);
INSERT INTO voo VALUES(11,'zit');
-- fails:
INSERT INTO voo VALUES(12,'zoo') RETURNING *, f1*2;
-- fails, incompatible list:
CREATE OR REPLACE RULE voo_i AS ON INSERT TO voo DO INSTEAD
INSERT INTO foo VALUES(new.*, 57) RETURNING *;
CREATE OR REPLACE RULE voo_i AS ON INSERT TO voo DO INSTEAD
INSERT INTO foo VALUES(new.*, 57) RETURNING f1, f2;
-- should still work
INSERT INTO voo VALUES(13,'zit2');
-- works now
INSERT INTO voo VALUES(14,'zoo2') RETURNING *;
SELECT * FROM foo;
SELECT * FROM voo;
CREATE OR REPLACE RULE voo_u AS ON UPDATE TO voo DO INSTEAD
UPDATE foo SET f1 = new.f1, f2 = new.f2 WHERE f1 = old.f1
RETURNING f1, f2;
update voo set f1 = f1 + 1 where f2 = 'zoo2';
update voo set f1 = f1 + 1 where f2 = 'zoo2' RETURNING *, f1*2;
SELECT * FROM foo;
SELECT * FROM voo;
CREATE OR REPLACE RULE voo_d AS ON DELETE TO voo DO INSTEAD
DELETE FROM foo WHERE f1 = old.f1
RETURNING f1, f2;
DELETE FROM foo WHERE f1 = 13;
DELETE FROM foo WHERE f2 = 'zit' RETURNING *;
SELECT * FROM foo;
SELECT * FROM voo;
-- Try a join case
CREATE TEMP TABLE joinme (f2j text, other int);
INSERT INTO joinme VALUES('more', 12345);
INSERT INTO joinme VALUES('zoo2', 54321);
INSERT INTO joinme VALUES('other', 0);
CREATE TEMP VIEW joinview AS
SELECT foo.*, other FROM foo JOIN joinme ON (f2 = f2j);
SELECT * FROM joinview;
CREATE RULE joinview_u AS ON UPDATE TO joinview DO INSTEAD
UPDATE foo SET f1 = new.f1, f3 = new.f3
FROM joinme WHERE f2 = f2j AND f2 = old.f2
RETURNING foo.*, other;
UPDATE joinview SET f1 = f1 + 1 WHERE f3 = 57 RETURNING *, other + 1;
SELECT * FROM joinview;
SELECT * FROM foo;
SELECT * FROM voo;
-- Check aliased target relation
INSERT INTO foo AS bar DEFAULT VALUES RETURNING *; -- ok
INSERT INTO foo AS bar DEFAULT VALUES RETURNING foo.*; -- fails, wrong name
INSERT INTO foo AS bar DEFAULT VALUES RETURNING bar.*; -- ok
INSERT INTO foo AS bar DEFAULT VALUES RETURNING bar.f3; -- ok