summaryrefslogtreecommitdiff
path: root/contrib/test_decoding
diff options
context:
space:
mode:
authorSimon Riggs2018-04-03 08:28:16 +0000
committerSimon Riggs2018-04-03 08:28:16 +0000
commitd204ef63776b8a00ca220adec23979091564e465 (patch)
tree5fa3d403db1d0377d85d20b9afb949c58855a37f /contrib/test_decoding
parentaa5877bb26347c58a34aee4e460eb1e1123bb096 (diff)
MERGE SQL Command following SQL:2016
MERGE performs actions that modify rows in the target table using a source table or query. MERGE provides a single SQL statement that can conditionally INSERT/UPDATE/DELETE rows a task that would other require multiple PL statements. e.g. MERGE INTO target AS t USING source AS s ON t.tid = s.sid WHEN MATCHED AND t.balance > s.delta THEN UPDATE SET balance = t.balance - s.delta WHEN MATCHED THEN DELETE WHEN NOT MATCHED AND s.delta > 0 THEN INSERT VALUES (s.sid, s.delta) WHEN NOT MATCHED THEN DO NOTHING; MERGE works with regular and partitioned tables, including column and row security enforcement, as well as support for row, statement and transition triggers. MERGE is optimized for OLTP and is parameterizable, though also useful for large scale ETL/ELT. MERGE is not intended to be used in preference to existing single SQL commands for INSERT, UPDATE or DELETE since there is some overhead. MERGE can be used statically from PL/pgSQL. MERGE does not yet support inheritance, write rules, RETURNING clauses, updatable views or foreign tables. MERGE follows SQL Standard per the most recent SQL:2016. Includes full tests and documentation, including full isolation tests to demonstrate the concurrent behavior. This version written from scratch in 2017 by Simon Riggs, using docs and tests originally written in 2009. Later work from Pavan Deolasee has been both complex and deep, leaving the lead author credit now in his hands. Extensive discussion of concurrency from Peter Geoghegan, with thanks for the time and effort contributed. Various issues reported via sqlsmith by Andreas Seltenreich Authors: Pavan Deolasee, Simon Riggs Reviewer: Peter Geoghegan, Amit Langote, Tomas Vondra, Simon Riggs Discussion: https://postgr.es/m/CANP8+jKitBSrB7oTgT9CY2i1ObfOt36z0XMraQc+Xrz8QB0nXA@mail.gmail.com https://postgr.es/m/CAH2-WzkJdBuxj9PO=2QaO9-3h3xGbQPZ34kJH=HukRekwM-GZg@mail.gmail.com
Diffstat (limited to 'contrib/test_decoding')
-rw-r--r--contrib/test_decoding/expected/ddl.out46
-rw-r--r--contrib/test_decoding/sql/ddl.sql16
2 files changed, 62 insertions, 0 deletions
diff --git a/contrib/test_decoding/expected/ddl.out b/contrib/test_decoding/expected/ddl.out
index b7c76469fc3..79c359d6e3d 100644
--- a/contrib/test_decoding/expected/ddl.out
+++ b/contrib/test_decoding/expected/ddl.out
@@ -192,6 +192,52 @@ SELECT data FROM pg_logical_slot_get_changes('regression_slot', NULL, NULL, 'inc
COMMIT
(33 rows)
+-- MERGE support
+BEGIN;
+MERGE INTO replication_example t
+ USING (SELECT i as id, i as data, i as num FROM generate_series(-20, 5) i) s
+ ON t.id = s.id
+ WHEN MATCHED AND t.id < 0 THEN
+ UPDATE SET somenum = somenum + 1
+ WHEN MATCHED AND t.id >= 0 THEN
+ DELETE
+ WHEN NOT MATCHED THEN
+ INSERT VALUES (s.*);
+COMMIT;
+/* display results */
+SELECT data FROM pg_logical_slot_get_changes('regression_slot', NULL, NULL, 'include-xids', '0', 'skip-empty-xacts', '1');
+ data
+--------------------------------------------------------------------------------------------------------------------------------------------------
+ BEGIN
+ table public.replication_example: INSERT: id[integer]:-20 somedata[integer]:-20 somenum[integer]:-20 zaphod1[integer]:null zaphod2[integer]:null
+ table public.replication_example: INSERT: id[integer]:-19 somedata[integer]:-19 somenum[integer]:-19 zaphod1[integer]:null zaphod2[integer]:null
+ table public.replication_example: INSERT: id[integer]:-18 somedata[integer]:-18 somenum[integer]:-18 zaphod1[integer]:null zaphod2[integer]:null
+ table public.replication_example: INSERT: id[integer]:-17 somedata[integer]:-17 somenum[integer]:-17 zaphod1[integer]:null zaphod2[integer]:null
+ table public.replication_example: INSERT: id[integer]:-16 somedata[integer]:-16 somenum[integer]:-16 zaphod1[integer]:null zaphod2[integer]:null
+ table public.replication_example: UPDATE: id[integer]:-15 somedata[integer]:-15 somenum[integer]:-14 zaphod1[integer]:null zaphod2[integer]:null
+ table public.replication_example: UPDATE: id[integer]:-14 somedata[integer]:-14 somenum[integer]:-13 zaphod1[integer]:null zaphod2[integer]:null
+ table public.replication_example: UPDATE: id[integer]:-13 somedata[integer]:-13 somenum[integer]:-12 zaphod1[integer]:null zaphod2[integer]:null
+ table public.replication_example: UPDATE: id[integer]:-12 somedata[integer]:-12 somenum[integer]:-11 zaphod1[integer]:null zaphod2[integer]:null
+ table public.replication_example: UPDATE: id[integer]:-11 somedata[integer]:-11 somenum[integer]:-10 zaphod1[integer]:null zaphod2[integer]:null
+ table public.replication_example: UPDATE: id[integer]:-10 somedata[integer]:-10 somenum[integer]:-9 zaphod1[integer]:null zaphod2[integer]:null
+ table public.replication_example: UPDATE: id[integer]:-9 somedata[integer]:-9 somenum[integer]:-8 zaphod1[integer]:null zaphod2[integer]:null
+ table public.replication_example: UPDATE: id[integer]:-8 somedata[integer]:-8 somenum[integer]:-7 zaphod1[integer]:null zaphod2[integer]:null
+ table public.replication_example: UPDATE: id[integer]:-7 somedata[integer]:-7 somenum[integer]:-6 zaphod1[integer]:null zaphod2[integer]:null
+ table public.replication_example: UPDATE: id[integer]:-6 somedata[integer]:-6 somenum[integer]:-5 zaphod1[integer]:null zaphod2[integer]:null
+ table public.replication_example: UPDATE: id[integer]:-5 somedata[integer]:-5 somenum[integer]:-4 zaphod1[integer]:null zaphod2[integer]:null
+ table public.replication_example: UPDATE: id[integer]:-4 somedata[integer]:-4 somenum[integer]:-3 zaphod1[integer]:null zaphod2[integer]:null
+ table public.replication_example: UPDATE: id[integer]:-3 somedata[integer]:-3 somenum[integer]:-2 zaphod1[integer]:null zaphod2[integer]:null
+ table public.replication_example: UPDATE: id[integer]:-2 somedata[integer]:-2 somenum[integer]:-1 zaphod1[integer]:null zaphod2[integer]:null
+ table public.replication_example: UPDATE: id[integer]:-1 somedata[integer]:-1 somenum[integer]:0 zaphod1[integer]:null zaphod2[integer]:null
+ table public.replication_example: DELETE: id[integer]:0
+ table public.replication_example: DELETE: id[integer]:1
+ table public.replication_example: DELETE: id[integer]:2
+ table public.replication_example: DELETE: id[integer]:3
+ table public.replication_example: DELETE: id[integer]:4
+ table public.replication_example: DELETE: id[integer]:5
+ COMMIT
+(28 rows)
+
CREATE TABLE tr_unique(id2 serial unique NOT NULL, data int);
INSERT INTO tr_unique(data) VALUES(10);
ALTER TABLE tr_unique RENAME TO tr_pkey;
diff --git a/contrib/test_decoding/sql/ddl.sql b/contrib/test_decoding/sql/ddl.sql
index c4b10a4cf9e..0e608b252fa 100644
--- a/contrib/test_decoding/sql/ddl.sql
+++ b/contrib/test_decoding/sql/ddl.sql
@@ -93,6 +93,22 @@ COMMIT;
/* display results */
SELECT data FROM pg_logical_slot_get_changes('regression_slot', NULL, NULL, 'include-xids', '0', 'skip-empty-xacts', '1');
+-- MERGE support
+BEGIN;
+MERGE INTO replication_example t
+ USING (SELECT i as id, i as data, i as num FROM generate_series(-20, 5) i) s
+ ON t.id = s.id
+ WHEN MATCHED AND t.id < 0 THEN
+ UPDATE SET somenum = somenum + 1
+ WHEN MATCHED AND t.id >= 0 THEN
+ DELETE
+ WHEN NOT MATCHED THEN
+ INSERT VALUES (s.*);
+COMMIT;
+
+/* display results */
+SELECT data FROM pg_logical_slot_get_changes('regression_slot', NULL, NULL, 'include-xids', '0', 'skip-empty-xacts', '1');
+
CREATE TABLE tr_unique(id2 serial unique NOT NULL, data int);
INSERT INTO tr_unique(data) VALUES(10);
ALTER TABLE tr_unique RENAME TO tr_pkey;