update.sql 26 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188189190191192193194195196197198199200201202203204205206207208209210211212213214215216217218219220221222223224225226227228229230231232233234235236237238239240241242243244245246247248249250251252253254255256257258259260261262263264265266267268269270271272273274275276277278279280281282283284285286287288289290291292293294295296297298299300301302303304305306307308309310311312313314315316317318319320321322323324325326327328329330331332333334335336337338339340341342343344345346347348349350351352353354355356357358359360361362363364365366367368369370371372373374375376377378379380381382383384385386387388389390391392393394395396397398399400401402403404405406407408409410411412413414415416417418419420421422423424425426427428429430431432433434435436437438439440441442443444445446447448449450451452453454455456457458459460461462463464465466467468469470471472473474475476477478479480481482483484485486487488489490491492493494495496497498499500501502503504505506507508509510511512513514515516517518519520521522523524525526527528529530531532533534535536537538539540541542543544545546547548549550551552553554555556557558559560561562563564565566567568569570571572573574575576577578579580581582583584585586587588589590591592593594595596597598599600601602603604605606607608609610611612613614615616617618619620621622623624625626627628629630631632633634635636637638639640641642643644645646647648649650651652653654655656657658659660661662663664665666667668669
  1. --
  2. -- UPDATE syntax tests
  3. --
  4. CREATE TABLE update_test (
  5. a INT DEFAULT 10,
  6. b INT,
  7. c TEXT
  8. );
  9. CREATE TABLE upsert_test (
  10. a INT PRIMARY KEY,
  11. b TEXT
  12. );
  13. INSERT INTO update_test VALUES (5, 10, 'foo');
  14. INSERT INTO update_test(b, a) VALUES (15, 10);
  15. SELECT * FROM update_test;
  16. UPDATE update_test SET a = DEFAULT, b = DEFAULT;
  17. SELECT * FROM update_test;
  18. -- aliases for the UPDATE target table
  19. UPDATE update_test AS t SET b = 10 WHERE t.a = 10;
  20. SELECT * FROM update_test;
  21. UPDATE update_test t SET b = t.b + 10 WHERE t.a = 10;
  22. SELECT * FROM update_test;
  23. --
  24. -- Test VALUES in FROM
  25. --
  26. UPDATE update_test SET a=v.i FROM (VALUES(100, 20)) AS v(i, j)
  27. WHERE update_test.b = v.j;
  28. SELECT * FROM update_test;
  29. -- fail, wrong data type:
  30. UPDATE update_test SET a = v.* FROM (VALUES(100, 20)) AS v(i, j)
  31. WHERE update_test.b = v.j;
  32. --
  33. -- Test multiple-set-clause syntax
  34. --
  35. INSERT INTO update_test SELECT a,b+1,c FROM update_test;
  36. SELECT * FROM update_test;
  37. UPDATE update_test SET (c,b,a) = ('bugle', b+11, DEFAULT) WHERE c = 'foo';
  38. SELECT * FROM update_test;
  39. UPDATE update_test SET (c,b) = ('car', a+b), a = a + 1 WHERE a = 10;
  40. SELECT * FROM update_test;
  41. -- fail, multi assignment to same column:
  42. UPDATE update_test SET (c,b) = ('car', a+b), b = a + 1 WHERE a = 10;
  43. -- uncorrelated sub-select:
  44. UPDATE update_test
  45. SET (b,a) = (select a,b from update_test where b = 41 and c = 'car')
  46. WHERE a = 100 AND b = 20;
  47. SELECT * FROM update_test;
  48. -- correlated sub-select:
  49. UPDATE update_test o
  50. SET (b,a) = (select a+1,b from update_test i
  51. where i.a=o.a and i.b=o.b and i.c is not distinct from o.c);
  52. SELECT * FROM update_test;
  53. -- fail, multiple rows supplied:
  54. UPDATE update_test SET (b,a) = (select a+1,b from update_test);
  55. -- set to null if no rows supplied:
  56. UPDATE update_test SET (b,a) = (select a+1,b from update_test where a = 1000)
  57. WHERE a = 11;
  58. SELECT * FROM update_test;
  59. -- *-expansion should work in this context:
  60. UPDATE update_test SET (a,b) = ROW(v.*) FROM (VALUES(21, 100)) AS v(i, j)
  61. WHERE update_test.a = v.i;
  62. -- you might expect this to work, but syntactically it's not a RowExpr:
  63. UPDATE update_test SET (a,b) = (v.*) FROM (VALUES(21, 101)) AS v(i, j)
  64. WHERE update_test.a = v.i;
  65. -- if an alias for the target table is specified, don't allow references
  66. -- to the original table name
  67. UPDATE update_test AS t SET b = update_test.b + 10 WHERE t.a = 10;
  68. -- Make sure that we can update to a TOASTed value.
  69. UPDATE update_test SET c = repeat('x', 10000) WHERE c = 'car';
  70. SELECT a, b, char_length(c) FROM update_test;
  71. -- Check multi-assignment with a Result node to handle a one-time filter.
  72. EXPLAIN (VERBOSE, COSTS OFF)
  73. UPDATE update_test t
  74. SET (a, b) = (SELECT b, a FROM update_test s WHERE s.a = t.a)
  75. WHERE CURRENT_USER = SESSION_USER;
  76. UPDATE update_test t
  77. SET (a, b) = (SELECT b, a FROM update_test s WHERE s.a = t.a)
  78. WHERE CURRENT_USER = SESSION_USER;
  79. SELECT a, b, char_length(c) FROM update_test;
  80. -- Test ON CONFLICT DO UPDATE
  81. INSERT INTO upsert_test VALUES(1, 'Boo'), (3, 'Zoo');
  82. -- uncorrelated sub-select:
  83. WITH aaa AS (SELECT 1 AS a, 'Foo' AS b) INSERT INTO upsert_test
  84. VALUES (1, 'Bar') ON CONFLICT(a)
  85. DO UPDATE SET (b, a) = (SELECT b, a FROM aaa) RETURNING *;
  86. -- correlated sub-select:
  87. INSERT INTO upsert_test VALUES (1, 'Baz'), (3, 'Zaz') ON CONFLICT(a)
  88. DO UPDATE SET (b, a) = (SELECT b || ', Correlated', a from upsert_test i WHERE i.a = upsert_test.a)
  89. RETURNING *;
  90. -- correlated sub-select (EXCLUDED.* alias):
  91. INSERT INTO upsert_test VALUES (1, 'Bat'), (3, 'Zot') ON CONFLICT(a)
  92. DO UPDATE SET (b, a) = (SELECT b || ', Excluded', a from upsert_test i WHERE i.a = excluded.a)
  93. RETURNING *;
  94. -- ON CONFLICT using system attributes in RETURNING, testing both the
  95. -- inserting and updating paths. See bug report at:
  96. -- https://www.postgresql.org/message-id/73436355-6432-49B1-92ED-1FE4F7E7E100%40finefun.com.au
  97. INSERT INTO upsert_test VALUES (2, 'Beeble') ON CONFLICT(a)
  98. DO UPDATE SET (b, a) = (SELECT b || ', Excluded', a from upsert_test i WHERE i.a = excluded.a)
  99. RETURNING tableoid::regclass, xmin = pg_current_xact_id()::xid AS xmin_correct, xmax = 0 AS xmax_correct;
  100. -- currently xmax is set after a conflict - that's probably not good,
  101. -- but it seems worthwhile to have to be explicit if that changes.
  102. INSERT INTO upsert_test VALUES (2, 'Brox') ON CONFLICT(a)
  103. DO UPDATE SET (b, a) = (SELECT b || ', Excluded', a from upsert_test i WHERE i.a = excluded.a)
  104. RETURNING tableoid::regclass, xmin = pg_current_xact_id()::xid AS xmin_correct, xmax = pg_current_xact_id()::xid AS xmax_correct;
  105. DROP TABLE update_test;
  106. DROP TABLE upsert_test;
  107. -- Test ON CONFLICT DO UPDATE with partitioned table and non-identical children
  108. CREATE TABLE upsert_test (
  109. a INT PRIMARY KEY,
  110. b TEXT
  111. ) PARTITION BY LIST (a);
  112. CREATE TABLE upsert_test_1 PARTITION OF upsert_test FOR VALUES IN (1);
  113. CREATE TABLE upsert_test_2 (b TEXT, a INT PRIMARY KEY);
  114. ALTER TABLE upsert_test ATTACH PARTITION upsert_test_2 FOR VALUES IN (2);
  115. INSERT INTO upsert_test VALUES(1, 'Boo'), (2, 'Zoo');
  116. -- uncorrelated sub-select:
  117. WITH aaa AS (SELECT 1 AS a, 'Foo' AS b) INSERT INTO upsert_test
  118. VALUES (1, 'Bar') ON CONFLICT(a)
  119. DO UPDATE SET (b, a) = (SELECT b, a FROM aaa) RETURNING *;
  120. -- correlated sub-select:
  121. WITH aaa AS (SELECT 1 AS ctea, ' Foo' AS cteb) INSERT INTO upsert_test
  122. VALUES (1, 'Bar'), (2, 'Baz') ON CONFLICT(a)
  123. DO UPDATE SET (b, a) = (SELECT upsert_test.b||cteb, upsert_test.a FROM aaa) RETURNING *;
  124. DROP TABLE upsert_test;
  125. ---------------------------
  126. -- UPDATE with row movement
  127. ---------------------------
  128. -- When a partitioned table receives an UPDATE to the partitioned key and the
  129. -- new values no longer meet the partition's bound, the row must be moved to
  130. -- the correct partition for the new partition key (if one exists). We must
  131. -- also ensure that updatable views on partitioned tables properly enforce any
  132. -- WITH CHECK OPTION that is defined. The situation with triggers in this case
  133. -- also requires thorough testing as partition key updates causing row
  134. -- movement convert UPDATEs into DELETE+INSERT.
  135. CREATE TABLE range_parted (
  136. a text,
  137. b bigint,
  138. c numeric,
  139. d int,
  140. e varchar
  141. ) PARTITION BY RANGE (a, b);
  142. -- Create partitions intentionally in descending bound order, so as to test
  143. -- that update-row-movement works with the leaf partitions not in bound order.
  144. CREATE TABLE part_b_20_b_30 (e varchar, c numeric, a text, b bigint, d int);
  145. ALTER TABLE range_parted ATTACH PARTITION part_b_20_b_30 FOR VALUES FROM ('b', 20) TO ('b', 30);
  146. CREATE TABLE part_b_10_b_20 (e varchar, c numeric, a text, b bigint, d int) PARTITION BY RANGE (c);
  147. CREATE TABLE part_b_1_b_10 PARTITION OF range_parted FOR VALUES FROM ('b', 1) TO ('b', 10);
  148. ALTER TABLE range_parted ATTACH PARTITION part_b_10_b_20 FOR VALUES FROM ('b', 10) TO ('b', 20);
  149. CREATE TABLE part_a_10_a_20 PARTITION OF range_parted FOR VALUES FROM ('a', 10) TO ('a', 20);
  150. CREATE TABLE part_a_1_a_10 PARTITION OF range_parted FOR VALUES FROM ('a', 1) TO ('a', 10);
  151. -- Check that partition-key UPDATE works sanely on a partitioned table that
  152. -- does not have any child partitions.
  153. UPDATE part_b_10_b_20 set b = b - 6;
  154. -- Create some more partitions following the above pattern of descending bound
  155. -- order, but let's make the situation a bit more complex by having the
  156. -- attribute numbers of the columns vary from their parent partition.
  157. CREATE TABLE part_c_100_200 (e varchar, c numeric, a text, b bigint, d int) PARTITION BY range (abs(d));
  158. ALTER TABLE part_c_100_200 DROP COLUMN e, DROP COLUMN c, DROP COLUMN a;
  159. ALTER TABLE part_c_100_200 ADD COLUMN c numeric, ADD COLUMN e varchar, ADD COLUMN a text;
  160. ALTER TABLE part_c_100_200 DROP COLUMN b;
  161. ALTER TABLE part_c_100_200 ADD COLUMN b bigint;
  162. CREATE TABLE part_d_1_15 PARTITION OF part_c_100_200 FOR VALUES FROM (1) TO (15);
  163. CREATE TABLE part_d_15_20 PARTITION OF part_c_100_200 FOR VALUES FROM (15) TO (20);
  164. ALTER TABLE part_b_10_b_20 ATTACH PARTITION part_c_100_200 FOR VALUES FROM (100) TO (200);
  165. CREATE TABLE part_c_1_100 (e varchar, d int, c numeric, b bigint, a text);
  166. ALTER TABLE part_b_10_b_20 ATTACH PARTITION part_c_1_100 FOR VALUES FROM (1) TO (100);
  167. \set init_range_parted 'truncate range_parted; insert into range_parted VALUES (''a'', 1, 1, 1), (''a'', 10, 200, 1), (''b'', 12, 96, 1), (''b'', 13, 97, 2), (''b'', 15, 105, 16), (''b'', 17, 105, 19)'
  168. \set show_data 'select tableoid::regclass::text COLLATE "C" partname, * from range_parted ORDER BY 1, 2, 3, 4, 5, 6'
  169. :init_range_parted;
  170. :show_data;
  171. -- The order of subplans should be in bound order
  172. EXPLAIN (costs off) UPDATE range_parted set c = c - 50 WHERE c > 97;
  173. -- fail, row movement happens only within the partition subtree.
  174. UPDATE part_c_100_200 set c = c - 20, d = c WHERE c = 105;
  175. -- fail, no partition key update, so no attempt to move tuple,
  176. -- but "a = 'a'" violates partition constraint enforced by root partition)
  177. UPDATE part_b_10_b_20 set a = 'a';
  178. -- ok, partition key update, no constraint violation
  179. UPDATE range_parted set d = d - 10 WHERE d > 10;
  180. -- ok, no partition key update, no constraint violation
  181. UPDATE range_parted set e = d;
  182. -- No row found
  183. UPDATE part_c_1_100 set c = c + 20 WHERE c = 98;
  184. -- ok, row movement
  185. UPDATE part_b_10_b_20 set c = c + 20 returning c, b, a;
  186. :show_data;
  187. -- fail, row movement happens only within the partition subtree.
  188. UPDATE part_b_10_b_20 set b = b - 6 WHERE c > 116 returning *;
  189. -- ok, row movement, with subset of rows moved into different partition.
  190. UPDATE range_parted set b = b - 6 WHERE c > 116 returning a, b + c;
  191. :show_data;
  192. -- Common table needed for multiple test scenarios.
  193. CREATE TABLE mintab(c1 int);
  194. INSERT into mintab VALUES (120);
  195. -- update partition key using updatable view.
  196. CREATE VIEW upview AS SELECT * FROM range_parted WHERE (select c > c1 FROM mintab) WITH CHECK OPTION;
  197. -- ok
  198. UPDATE upview set c = 199 WHERE b = 4;
  199. -- fail, check option violation
  200. UPDATE upview set c = 120 WHERE b = 4;
  201. -- fail, row movement with check option violation
  202. UPDATE upview set a = 'b', b = 15, c = 120 WHERE b = 4;
  203. -- ok, row movement, check option passes
  204. UPDATE upview set a = 'b', b = 15 WHERE b = 4;
  205. :show_data;
  206. -- cleanup
  207. DROP VIEW upview;
  208. -- RETURNING having whole-row vars.
  209. :init_range_parted;
  210. UPDATE range_parted set c = 95 WHERE a = 'b' and b > 10 and c > 100 returning (range_parted), *;
  211. :show_data;
  212. -- Transition tables with update row movement
  213. :init_range_parted;
  214. CREATE FUNCTION trans_updatetrigfunc() RETURNS trigger LANGUAGE plpgsql AS
  215. $$
  216. begin
  217. raise notice 'trigger = %, old table = %, new table = %',
  218. TG_NAME,
  219. (select string_agg(old_table::text, ', ' ORDER BY a) FROM old_table),
  220. (select string_agg(new_table::text, ', ' ORDER BY a) FROM new_table);
  221. return null;
  222. end;
  223. $$;
  224. CREATE TRIGGER trans_updatetrig
  225. AFTER UPDATE ON range_parted REFERENCING OLD TABLE AS old_table NEW TABLE AS new_table
  226. FOR EACH STATEMENT EXECUTE PROCEDURE trans_updatetrigfunc();
  227. UPDATE range_parted set c = (case when c = 96 then 110 else c + 1 end ) WHERE a = 'b' and b > 10 and c >= 96;
  228. :show_data;
  229. :init_range_parted;
  230. -- Enabling OLD TABLE capture for both DELETE as well as UPDATE stmt triggers
  231. -- should not cause DELETEd rows to be captured twice. Similar thing for
  232. -- INSERT triggers and inserted rows.
  233. CREATE TRIGGER trans_deletetrig
  234. AFTER DELETE ON range_parted REFERENCING OLD TABLE AS old_table
  235. FOR EACH STATEMENT EXECUTE PROCEDURE trans_updatetrigfunc();
  236. CREATE TRIGGER trans_inserttrig
  237. AFTER INSERT ON range_parted REFERENCING NEW TABLE AS new_table
  238. FOR EACH STATEMENT EXECUTE PROCEDURE trans_updatetrigfunc();
  239. UPDATE range_parted set c = c + 50 WHERE a = 'b' and b > 10 and c >= 96;
  240. :show_data;
  241. DROP TRIGGER trans_deletetrig ON range_parted;
  242. DROP TRIGGER trans_inserttrig ON range_parted;
  243. -- Don't drop trans_updatetrig yet. It is required below.
  244. -- Test with transition tuple conversion happening for rows moved into the
  245. -- new partition. This requires a trigger that references transition table
  246. -- (we already have trans_updatetrig). For inserted rows, the conversion
  247. -- is not usually needed, because the original tuple is already compatible with
  248. -- the desired transition tuple format. But conversion happens when there is a
  249. -- BR trigger because the trigger can change the inserted row. So install a
  250. -- BR triggers on those child partitions where the rows will be moved.
  251. CREATE FUNCTION func_parted_mod_b() RETURNS trigger AS $$
  252. BEGIN
  253. NEW.b = NEW.b + 1;
  254. return NEW;
  255. END $$ language plpgsql;
  256. CREATE TRIGGER trig_c1_100 BEFORE UPDATE OR INSERT ON part_c_1_100
  257. FOR EACH ROW EXECUTE PROCEDURE func_parted_mod_b();
  258. CREATE TRIGGER trig_d1_15 BEFORE UPDATE OR INSERT ON part_d_1_15
  259. FOR EACH ROW EXECUTE PROCEDURE func_parted_mod_b();
  260. CREATE TRIGGER trig_d15_20 BEFORE UPDATE OR INSERT ON part_d_15_20
  261. FOR EACH ROW EXECUTE PROCEDURE func_parted_mod_b();
  262. :init_range_parted;
  263. UPDATE range_parted set c = (case when c = 96 then 110 else c + 1 end) WHERE a = 'b' and b > 10 and c >= 96;
  264. :show_data;
  265. :init_range_parted;
  266. UPDATE range_parted set c = c + 50 WHERE a = 'b' and b > 10 and c >= 96;
  267. :show_data;
  268. -- Case where per-partition tuple conversion map array is allocated, but the
  269. -- map is not required for the particular tuple that is routed, thanks to
  270. -- matching table attributes of the partition and the target table.
  271. :init_range_parted;
  272. UPDATE range_parted set b = 15 WHERE b = 1;
  273. :show_data;
  274. DROP TRIGGER trans_updatetrig ON range_parted;
  275. DROP TRIGGER trig_c1_100 ON part_c_1_100;
  276. DROP TRIGGER trig_d1_15 ON part_d_1_15;
  277. DROP TRIGGER trig_d15_20 ON part_d_15_20;
  278. DROP FUNCTION func_parted_mod_b();
  279. -- RLS policies with update-row-movement
  280. -----------------------------------------
  281. ALTER TABLE range_parted ENABLE ROW LEVEL SECURITY;
  282. CREATE USER regress_range_parted_user;
  283. GRANT ALL ON range_parted, mintab TO regress_range_parted_user;
  284. CREATE POLICY seeall ON range_parted AS PERMISSIVE FOR SELECT USING (true);
  285. CREATE POLICY policy_range_parted ON range_parted for UPDATE USING (true) WITH CHECK (c % 2 = 0);
  286. :init_range_parted;
  287. SET SESSION AUTHORIZATION regress_range_parted_user;
  288. -- This should fail with RLS violation error while moving row from
  289. -- part_a_10_a_20 to part_d_1_15, because we are setting 'c' to an odd number.
  290. UPDATE range_parted set a = 'b', c = 151 WHERE a = 'a' and c = 200;
  291. RESET SESSION AUTHORIZATION;
  292. -- Create a trigger on part_d_1_15
  293. CREATE FUNCTION func_d_1_15() RETURNS trigger AS $$
  294. BEGIN
  295. NEW.c = NEW.c + 1; -- Make even numbers odd, or vice versa
  296. return NEW;
  297. END $$ LANGUAGE plpgsql;
  298. CREATE TRIGGER trig_d_1_15 BEFORE INSERT ON part_d_1_15
  299. FOR EACH ROW EXECUTE PROCEDURE func_d_1_15();
  300. :init_range_parted;
  301. SET SESSION AUTHORIZATION regress_range_parted_user;
  302. -- Here, RLS checks should succeed while moving row from part_a_10_a_20 to
  303. -- part_d_1_15. Even though the UPDATE is setting 'c' to an odd number, the
  304. -- trigger at the destination partition again makes it an even number.
  305. UPDATE range_parted set a = 'b', c = 151 WHERE a = 'a' and c = 200;
  306. RESET SESSION AUTHORIZATION;
  307. :init_range_parted;
  308. SET SESSION AUTHORIZATION regress_range_parted_user;
  309. -- This should fail with RLS violation error. Even though the UPDATE is setting
  310. -- 'c' to an even number, the trigger at the destination partition again makes
  311. -- it an odd number.
  312. UPDATE range_parted set a = 'b', c = 150 WHERE a = 'a' and c = 200;
  313. -- Cleanup
  314. RESET SESSION AUTHORIZATION;
  315. DROP TRIGGER trig_d_1_15 ON part_d_1_15;
  316. DROP FUNCTION func_d_1_15();
  317. -- Policy expression contains SubPlan
  318. RESET SESSION AUTHORIZATION;
  319. :init_range_parted;
  320. CREATE POLICY policy_range_parted_subplan on range_parted
  321. AS RESTRICTIVE for UPDATE USING (true)
  322. WITH CHECK ((SELECT range_parted.c <= c1 FROM mintab));
  323. SET SESSION AUTHORIZATION regress_range_parted_user;
  324. -- fail, mintab has row with c1 = 120
  325. UPDATE range_parted set a = 'b', c = 122 WHERE a = 'a' and c = 200;
  326. -- ok
  327. UPDATE range_parted set a = 'b', c = 120 WHERE a = 'a' and c = 200;
  328. -- RLS policy expression contains whole row.
  329. RESET SESSION AUTHORIZATION;
  330. :init_range_parted;
  331. CREATE POLICY policy_range_parted_wholerow on range_parted AS RESTRICTIVE for UPDATE USING (true)
  332. WITH CHECK (range_parted = row('b', 10, 112, 1, NULL)::range_parted);
  333. SET SESSION AUTHORIZATION regress_range_parted_user;
  334. -- ok, should pass the RLS check
  335. UPDATE range_parted set a = 'b', c = 112 WHERE a = 'a' and c = 200;
  336. RESET SESSION AUTHORIZATION;
  337. :init_range_parted;
  338. SET SESSION AUTHORIZATION regress_range_parted_user;
  339. -- fail, the whole row RLS check should fail
  340. UPDATE range_parted set a = 'b', c = 116 WHERE a = 'a' and c = 200;
  341. -- Cleanup
  342. RESET SESSION AUTHORIZATION;
  343. DROP POLICY policy_range_parted ON range_parted;
  344. DROP POLICY policy_range_parted_subplan ON range_parted;
  345. DROP POLICY policy_range_parted_wholerow ON range_parted;
  346. REVOKE ALL ON range_parted, mintab FROM regress_range_parted_user;
  347. DROP USER regress_range_parted_user;
  348. DROP TABLE mintab;
  349. -- statement triggers with update row movement
  350. ---------------------------------------------------
  351. :init_range_parted;
  352. CREATE FUNCTION trigfunc() returns trigger language plpgsql as
  353. $$
  354. begin
  355. raise notice 'trigger = % fired on table % during %',
  356. TG_NAME, TG_TABLE_NAME, TG_OP;
  357. return null;
  358. end;
  359. $$;
  360. -- Triggers on root partition
  361. CREATE TRIGGER parent_delete_trig
  362. AFTER DELETE ON range_parted for each statement execute procedure trigfunc();
  363. CREATE TRIGGER parent_update_trig
  364. AFTER UPDATE ON range_parted for each statement execute procedure trigfunc();
  365. CREATE TRIGGER parent_insert_trig
  366. AFTER INSERT ON range_parted for each statement execute procedure trigfunc();
  367. -- Triggers on leaf partition part_c_1_100
  368. CREATE TRIGGER c1_delete_trig
  369. AFTER DELETE ON part_c_1_100 for each statement execute procedure trigfunc();
  370. CREATE TRIGGER c1_update_trig
  371. AFTER UPDATE ON part_c_1_100 for each statement execute procedure trigfunc();
  372. CREATE TRIGGER c1_insert_trig
  373. AFTER INSERT ON part_c_1_100 for each statement execute procedure trigfunc();
  374. -- Triggers on leaf partition part_d_1_15
  375. CREATE TRIGGER d1_delete_trig
  376. AFTER DELETE ON part_d_1_15 for each statement execute procedure trigfunc();
  377. CREATE TRIGGER d1_update_trig
  378. AFTER UPDATE ON part_d_1_15 for each statement execute procedure trigfunc();
  379. CREATE TRIGGER d1_insert_trig
  380. AFTER INSERT ON part_d_1_15 for each statement execute procedure trigfunc();
  381. -- Triggers on leaf partition part_d_15_20
  382. CREATE TRIGGER d15_delete_trig
  383. AFTER DELETE ON part_d_15_20 for each statement execute procedure trigfunc();
  384. CREATE TRIGGER d15_update_trig
  385. AFTER UPDATE ON part_d_15_20 for each statement execute procedure trigfunc();
  386. CREATE TRIGGER d15_insert_trig
  387. AFTER INSERT ON part_d_15_20 for each statement execute procedure trigfunc();
  388. -- Move all rows from part_c_100_200 to part_c_1_100. None of the delete or
  389. -- insert statement triggers should be fired.
  390. UPDATE range_parted set c = c - 50 WHERE c > 97;
  391. :show_data;
  392. DROP TRIGGER parent_delete_trig ON range_parted;
  393. DROP TRIGGER parent_update_trig ON range_parted;
  394. DROP TRIGGER parent_insert_trig ON range_parted;
  395. DROP TRIGGER c1_delete_trig ON part_c_1_100;
  396. DROP TRIGGER c1_update_trig ON part_c_1_100;
  397. DROP TRIGGER c1_insert_trig ON part_c_1_100;
  398. DROP TRIGGER d1_delete_trig ON part_d_1_15;
  399. DROP TRIGGER d1_update_trig ON part_d_1_15;
  400. DROP TRIGGER d1_insert_trig ON part_d_1_15;
  401. DROP TRIGGER d15_delete_trig ON part_d_15_20;
  402. DROP TRIGGER d15_update_trig ON part_d_15_20;
  403. DROP TRIGGER d15_insert_trig ON part_d_15_20;
  404. -- Creating default partition for range
  405. :init_range_parted;
  406. create table part_def partition of range_parted default;
  407. \d+ part_def
  408. insert into range_parted values ('c', 9);
  409. -- ok
  410. update part_def set a = 'd' where a = 'c';
  411. -- fail
  412. update part_def set a = 'a' where a = 'd';
  413. :show_data;
  414. -- Update row movement from non-default to default partition.
  415. -- fail, default partition is not under part_a_10_a_20;
  416. UPDATE part_a_10_a_20 set a = 'ad' WHERE a = 'a';
  417. -- ok
  418. UPDATE range_parted set a = 'ad' WHERE a = 'a';
  419. UPDATE range_parted set a = 'bd' WHERE a = 'b';
  420. :show_data;
  421. -- Update row movement from default to non-default partitions.
  422. -- ok
  423. UPDATE range_parted set a = 'a' WHERE a = 'ad';
  424. UPDATE range_parted set a = 'b' WHERE a = 'bd';
  425. :show_data;
  426. -- Cleanup: range_parted no longer needed.
  427. DROP TABLE range_parted;
  428. CREATE TABLE list_parted (
  429. a text,
  430. b int
  431. ) PARTITION BY list (a);
  432. CREATE TABLE list_part1 PARTITION OF list_parted for VALUES in ('a', 'b');
  433. CREATE TABLE list_default PARTITION OF list_parted default;
  434. INSERT into list_part1 VALUES ('a', 1);
  435. INSERT into list_default VALUES ('d', 10);
  436. -- fail
  437. UPDATE list_default set a = 'a' WHERE a = 'd';
  438. -- ok
  439. UPDATE list_default set a = 'x' WHERE a = 'd';
  440. DROP TABLE list_parted;
  441. -- Test retrieval of system columns with non-consistent partition row types.
  442. -- This is only partially supported, as seen in the results.
  443. create table utrtest (a int, b text) partition by list (a);
  444. create table utr1 (a int check (a in (1)), q text, b text);
  445. create table utr2 (a int check (a in (2)), b text);
  446. alter table utr1 drop column q;
  447. alter table utrtest attach partition utr1 for values in (1);
  448. alter table utrtest attach partition utr2 for values in (2);
  449. insert into utrtest values (1, 'foo')
  450. returning *, tableoid::regclass, xmin = pg_current_xact_id()::xid as xmin_ok;
  451. insert into utrtest values (2, 'bar')
  452. returning *, tableoid::regclass, xmin = pg_current_xact_id()::xid as xmin_ok; -- fails
  453. insert into utrtest values (2, 'bar')
  454. returning *, tableoid::regclass;
  455. update utrtest set b = b || b from (values (1), (2)) s(x) where a = s.x
  456. returning *, tableoid::regclass, xmin = pg_current_xact_id()::xid as xmin_ok;
  457. update utrtest set a = 3 - a from (values (1), (2)) s(x) where a = s.x
  458. returning *, tableoid::regclass, xmin = pg_current_xact_id()::xid as xmin_ok; -- fails
  459. update utrtest set a = 3 - a from (values (1), (2)) s(x) where a = s.x
  460. returning *, tableoid::regclass;
  461. delete from utrtest
  462. returning *, tableoid::regclass, xmax = pg_current_xact_id()::xid as xmax_ok;
  463. drop table utrtest;
  464. --------------
  465. -- Some more update-partition-key test scenarios below. This time use list
  466. -- partitions.
  467. --------------
  468. -- Setup for list partitions
  469. CREATE TABLE list_parted (a numeric, b int, c int8) PARTITION BY list (a);
  470. CREATE TABLE sub_parted PARTITION OF list_parted for VALUES in (1) PARTITION BY list (b);
  471. CREATE TABLE sub_part1(b int, c int8, a numeric);
  472. ALTER TABLE sub_parted ATTACH PARTITION sub_part1 for VALUES in (1);
  473. CREATE TABLE sub_part2(b int, c int8, a numeric);
  474. ALTER TABLE sub_parted ATTACH PARTITION sub_part2 for VALUES in (2);
  475. CREATE TABLE list_part1(a numeric, b int, c int8);
  476. ALTER TABLE list_parted ATTACH PARTITION list_part1 for VALUES in (2,3);
  477. INSERT into list_parted VALUES (2,5,50);
  478. INSERT into list_parted VALUES (3,6,60);
  479. INSERT into sub_parted VALUES (1,1,60);
  480. INSERT into sub_parted VALUES (1,2,10);
  481. -- Test partition constraint violation when intermediate ancestor is used and
  482. -- constraint is inherited from upper root.
  483. UPDATE sub_parted set a = 2 WHERE c = 10;
  484. -- Test update-partition-key, where the unpruned partitions do not have their
  485. -- partition keys updated.
  486. SELECT tableoid::regclass::text, * FROM list_parted WHERE a = 2 ORDER BY 1;
  487. UPDATE list_parted set b = c + a WHERE a = 2;
  488. SELECT tableoid::regclass::text, * FROM list_parted WHERE a = 2 ORDER BY 1;
  489. -- Test the case where BR UPDATE triggers change the partition key.
  490. CREATE FUNCTION func_parted_mod_b() returns trigger as $$
  491. BEGIN
  492. NEW.b = 2; -- This is changing partition key column.
  493. return NEW;
  494. END $$ LANGUAGE plpgsql;
  495. CREATE TRIGGER parted_mod_b before update on sub_part1
  496. for each row execute procedure func_parted_mod_b();
  497. SELECT tableoid::regclass::text, * FROM list_parted ORDER BY 1, 2, 3, 4;
  498. -- This should do the tuple routing even though there is no explicit
  499. -- partition-key update, because there is a trigger on sub_part1.
  500. UPDATE list_parted set c = 70 WHERE b = 1;
  501. SELECT tableoid::regclass::text, * FROM list_parted ORDER BY 1, 2, 3, 4;
  502. DROP TRIGGER parted_mod_b ON sub_part1;
  503. -- If BR DELETE trigger prevented DELETE from happening, we should also skip
  504. -- the INSERT if that delete is part of UPDATE=>DELETE+INSERT.
  505. CREATE OR REPLACE FUNCTION func_parted_mod_b() returns trigger as $$
  506. BEGIN
  507. raise notice 'Trigger: Got OLD row %, but returning NULL', OLD;
  508. return NULL;
  509. END $$ LANGUAGE plpgsql;
  510. CREATE TRIGGER trig_skip_delete before delete on sub_part2
  511. for each row execute procedure func_parted_mod_b();
  512. UPDATE list_parted set b = 1 WHERE c = 70;
  513. SELECT tableoid::regclass::text, * FROM list_parted ORDER BY 1, 2, 3, 4;
  514. -- Drop the trigger. Now the row should be moved.
  515. DROP TRIGGER trig_skip_delete ON sub_part2;
  516. UPDATE list_parted set b = 1 WHERE c = 70;
  517. SELECT tableoid::regclass::text, * FROM list_parted ORDER BY 1, 2, 3, 4;
  518. DROP FUNCTION func_parted_mod_b();
  519. -- UPDATE partition-key with FROM clause. If join produces multiple output
  520. -- rows for the same row to be modified, we should tuple-route the row only
  521. -- once. There should not be any rows inserted.
  522. CREATE TABLE non_parted (id int);
  523. INSERT into non_parted VALUES (1), (1), (1), (2), (2), (2), (3), (3), (3);
  524. UPDATE list_parted t1 set a = 2 FROM non_parted t2 WHERE t1.a = t2.id and a = 1;
  525. SELECT tableoid::regclass::text, * FROM list_parted ORDER BY 1, 2, 3, 4;
  526. DROP TABLE non_parted;
  527. -- Cleanup: list_parted no longer needed.
  528. DROP TABLE list_parted;
  529. -- create custom operator class and hash function, for the same reason
  530. -- explained in alter_table.sql
  531. create or replace function dummy_hashint4(a int4, seed int8) returns int8 as
  532. $$ begin return (a + seed); end; $$ language 'plpgsql' immutable;
  533. create operator class custom_opclass for type int4 using hash as
  534. operator 1 = , function 2 dummy_hashint4(int4, int8);
  535. create table hash_parted (
  536. a int,
  537. b int
  538. ) partition by hash (a custom_opclass, b custom_opclass);
  539. create table hpart1 partition of hash_parted for values with (modulus 2, remainder 1);
  540. create table hpart2 partition of hash_parted for values with (modulus 4, remainder 2);
  541. create table hpart3 partition of hash_parted for values with (modulus 8, remainder 0);
  542. create table hpart4 partition of hash_parted for values with (modulus 8, remainder 4);
  543. insert into hpart1 values (1, 1);
  544. insert into hpart2 values (2, 5);
  545. insert into hpart4 values (3, 4);
  546. -- fail
  547. update hpart1 set a = 3, b=4 where a = 1;
  548. -- ok, row movement
  549. update hash_parted set b = b - 1 where b = 1;
  550. -- ok
  551. update hash_parted set b = b + 8 where b = 1;
  552. -- cleanup
  553. drop table hash_parted;
  554. drop operator class custom_opclass using hash;
  555. drop function dummy_hashint4(a int4, seed int8);