-- -- UPDATE syntax tests -- CREATE TABLE update_test ( a INT DEFAULT 10, b INT, c TEXT ); CREATE TABLE upsert_test ( a INT PRIMARY KEY, b TEXT ); INSERT INTO update_test VALUES (5, 10, 'foo'); INSERT INTO update_test(b, a) VALUES (15, 10); SELECT * FROM update_test; UPDATE update_test SET a = DEFAULT, b = DEFAULT; SELECT * FROM update_test; -- aliases for the UPDATE target table UPDATE update_test AS t SET b = 10 WHERE t.a = 10; SELECT * FROM update_test; UPDATE update_test t SET b = t.b + 10 WHERE t.a = 10; SELECT * FROM update_test; -- -- Test VALUES in FROM -- UPDATE update_test SET a=v.i FROM (VALUES(100, 20)) AS v(i, j) WHERE update_test.b = v.j; SELECT * FROM update_test; -- fail, wrong data type: UPDATE update_test SET a = v.* FROM (VALUES(100, 20)) AS v(i, j) WHERE update_test.b = v.j; -- -- Test multiple-set-clause syntax -- INSERT INTO update_test SELECT a,b+1,c FROM update_test; SELECT * FROM update_test; UPDATE update_test SET (c,b,a) = ('bugle', b+11, DEFAULT) WHERE c = 'foo'; SELECT * FROM update_test; UPDATE update_test SET (c,b) = ('car', a+b), a = a + 1 WHERE a = 10; SELECT * FROM update_test; -- fail, multi assignment to same column: UPDATE update_test SET (c,b) = ('car', a+b), b = a + 1 WHERE a = 10; -- uncorrelated sub-select: UPDATE update_test SET (b,a) = (select a,b from update_test where b = 41 and c = 'car') WHERE a = 100 AND b = 20; SELECT * FROM update_test; -- correlated sub-select: UPDATE update_test o SET (b,a) = (select a+1,b from update_test i where i.a=o.a and i.b=o.b and i.c is not distinct from o.c); SELECT * FROM update_test; -- fail, multiple rows supplied: UPDATE update_test SET (b,a) = (select a+1,b from update_test); -- set to null if no rows supplied: UPDATE update_test SET (b,a) = (select a+1,b from update_test where a = 1000) WHERE a = 11; SELECT * FROM update_test; -- *-expansion should work in this context: UPDATE update_test SET (a,b) = ROW(v.*) FROM (VALUES(21, 100)) AS v(i, j) WHERE update_test.a = v.i; -- you might expect this to work, but syntactically it's not a RowExpr: UPDATE update_test SET (a,b) = (v.*) FROM (VALUES(21, 101)) AS v(i, j) WHERE update_test.a = v.i; -- if an alias for the target table is specified, don't allow references -- to the original table name UPDATE update_test AS t SET b = update_test.b + 10 WHERE t.a = 10; -- Make sure that we can update to a TOASTed value. UPDATE update_test SET c = repeat('x', 10000) WHERE c = 'car'; SELECT a, b, char_length(c) FROM update_test; -- Test ON CONFLICT DO UPDATE INSERT INTO upsert_test VALUES(1, 'Boo'); -- uncorrelated sub-select: WITH aaa AS (SELECT 1 AS a, 'Foo' AS b) INSERT INTO upsert_test VALUES (1, 'Bar') ON CONFLICT(a) DO UPDATE SET (b, a) = (SELECT b, a FROM aaa) RETURNING *; -- correlated sub-select: INSERT INTO upsert_test VALUES (1, 'Baz') ON CONFLICT(a) DO UPDATE SET (b, a) = (SELECT b || ', Correlated', a from upsert_test i WHERE i.a = upsert_test.a) RETURNING *; -- correlated sub-select (EXCLUDED.* alias): INSERT INTO upsert_test VALUES (1, 'Bat') ON CONFLICT(a) DO UPDATE SET (b, a) = (SELECT b || ', Excluded', a from upsert_test i WHERE i.a = excluded.a) RETURNING *; DROP TABLE update_test; DROP TABLE upsert_test; -- update to a partition should check partition bound constraint for the new tuple create table range_parted ( a text, b int ) partition by range (a, b); create table part_a_1_a_10 partition of range_parted for values from ('a', 1) to ('a', 10); create table part_a_10_a_20 partition of range_parted for values from ('a', 10) to ('a', 20); create table part_b_1_b_10 partition of range_parted for values from ('b', 1) to ('b', 10); create table part_b_10_b_20 partition of range_parted for values from ('b', 10) to ('b', 20); insert into part_a_1_a_10 values ('a', 1); insert into part_b_10_b_20 values ('b', 10); -- fail update part_a_1_a_10 set a = 'b' where a = 'a'; update range_parted set b = b - 1 where b = 10; -- ok update range_parted set b = b + 1 where b = 10; -- Creating default partition for range create table part_def partition of range_parted default; \d+ part_def insert into range_parted values ('c', 9); -- ok update part_def set a = 'd' where a = 'c'; -- fail update part_def set a = 'a' where a = 'd'; create table list_parted ( a text, b int ) partition by list (a); create table list_part1 partition of list_parted for values in ('a', 'b'); create table list_default partition of list_parted default; insert into list_part1 values ('a', 1); insert into list_default values ('d', 10); -- fail update list_default set a = 'a' where a = 'd'; -- ok update list_default set a = 'x' where a = 'd'; -- create custom operator class and hash function, for the same reason -- explained in alter_table.sql create or replace function dummy_hashint4(a int4, seed int8) returns int8 as $$ begin return (a + seed); end; $$ language 'plpgsql' immutable; create operator class custom_opclass for type int4 using hash as operator 1 = , function 2 dummy_hashint4(int4, int8); create table hash_parted ( a int, b int ) partition by hash (a custom_opclass, b custom_opclass); create table hpart1 partition of hash_parted for values with (modulus 2, remainder 1); create table hpart2 partition of hash_parted for values with (modulus 4, remainder 2); create table hpart3 partition of hash_parted for values with (modulus 8, remainder 0); create table hpart4 partition of hash_parted for values with (modulus 8, remainder 4); insert into hpart1 values (1, 1); insert into hpart2 values (2, 5); insert into hpart4 values (3, 4); -- fail update hpart1 set a = 3, b=4 where a = 1; update hash_parted set b = b - 1 where b = 1; -- ok update hash_parted set b = b + 8 where b = 1; -- cleanup drop table range_parted; drop table list_parted; drop table hash_parted; drop operator class custom_opclass using hash; drop function dummy_hashint4(a int4, seed int8);