From 7103ebb7aae8ab8076b7e85f335ceb8fe799097c Mon Sep 17 00:00:00 2001 From: Alvaro Herrera Date: Mon, 28 Mar 2022 16:45:58 +0200 Subject: [PATCH] Add support for MERGE SQL command MIME-Version: 1.0 Content-Type: text/plain; charset=UTF-8 Content-Transfer-Encoding: 8bit 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 otherwise require multiple PL statements. For example, 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 tables, partitioned tables and inheritance hierarchies, including column and row security enforcement, as well as support for row and statement triggers and transition tables therein. 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 from PL/pgSQL. MERGE does not support targetting updatable views or foreign tables, and RETURNING clauses are not allowed either. These limitations are likely fixable with sufficient effort. Rewrite rules are also not supported, but it's not clear that we'd want to support them. Author: Pavan Deolasee Author: Álvaro Herrera Author: Amit Langote Author: Simon Riggs Reviewed-by: Peter Eisentraut Reviewed-by: Andres Freund (earlier versions) Reviewed-by: Peter Geoghegan (earlier versions) Reviewed-by: Robert Haas (earlier versions) Reviewed-by: Japin Li Reviewed-by: Justin Pryzby Reviewed-by: Tomas Vondra Reviewed-by: Zhihong Yu Discussion: https://postgr.es/m/CANP8+jKitBSrB7oTgT9CY2i1ObfOt36z0XMraQc+Xrz8QB0nXA@mail.gmail.com Discussion: https://postgr.es/m/CAH2-WzkJdBuxj9PO=2QaO9-3h3xGbQPZ34kJH=HukRekwM-GZg@mail.gmail.com Discussion: https://postgr.es/m/20201231134736.GA25392@alvherre.pgsql --- contrib/test_decoding/expected/ddl.out | 46 + contrib/test_decoding/sql/ddl.sql | 16 + doc/src/sgml/libpq.sgml | 8 +- doc/src/sgml/mvcc.sgml | 34 +- doc/src/sgml/plpgsql.sgml | 5 +- doc/src/sgml/ref/allfiles.sgml | 1 + doc/src/sgml/ref/create_policy.sgml | 23 +- doc/src/sgml/ref/insert.sgml | 11 +- doc/src/sgml/ref/merge.sgml | 620 ++++++ doc/src/sgml/reference.sgml | 1 + doc/src/sgml/trigger.sgml | 22 + src/backend/catalog/sql_features.txt | 6 +- src/backend/commands/explain.c | 35 + src/backend/commands/trigger.c | 126 +- src/backend/executor/README | 41 +- src/backend/executor/execMain.c | 16 + src/backend/executor/execPartition.c | 113 +- src/backend/executor/execReplication.c | 2 +- src/backend/executor/nodeModifyTable.c | 936 +++++++- src/backend/executor/spi.c | 3 + src/backend/nodes/copyfuncs.c | 55 + src/backend/nodes/equalfuncs.c | 49 + src/backend/nodes/nodeFuncs.c | 59 +- src/backend/nodes/outfuncs.c | 36 + src/backend/nodes/readfuncs.c | 43 + src/backend/optimizer/plan/createplan.c | 15 +- src/backend/optimizer/plan/planner.c | 64 +- src/backend/optimizer/plan/setrefs.c | 64 +- src/backend/optimizer/prep/prepjointree.c | 91 + src/backend/optimizer/prep/preptlist.c | 37 + src/backend/optimizer/util/appendinfo.c | 19 +- src/backend/optimizer/util/pathnode.c | 11 +- src/backend/optimizer/util/plancat.c | 4 + src/backend/parser/Makefile | 1 + src/backend/parser/analyze.c | 20 +- src/backend/parser/gram.y | 180 +- src/backend/parser/parse_agg.c | 10 + src/backend/parser/parse_collate.c | 1 + src/backend/parser/parse_expr.c | 4 + src/backend/parser/parse_func.c | 3 + src/backend/parser/parse_merge.c | 415 ++++ src/backend/parser/parse_relation.c | 23 +- src/backend/parser/parse_target.c | 3 +- src/backend/rewrite/rewriteHandler.c | 41 +- src/backend/rewrite/rowsecurity.c | 106 +- src/backend/tcop/pquery.c | 3 + src/backend/tcop/utility.c | 16 + src/backend/utils/adt/ruleutils.c | 9 +- src/bin/psql/tab-complete.c | 69 +- src/include/commands/trigger.h | 4 +- src/include/executor/nodeModifyTable.h | 3 + src/include/executor/spi.h | 1 + src/include/nodes/execnodes.h | 36 +- src/include/nodes/nodes.h | 7 +- src/include/nodes/parsenodes.h | 61 +- src/include/nodes/pathnodes.h | 6 +- src/include/nodes/plannodes.h | 7 +- src/include/optimizer/pathnode.h | 2 +- src/include/optimizer/prep.h | 1 + src/include/parser/analyze.h | 5 + src/include/parser/kwlist.h | 2 + src/include/parser/parse_merge.h | 21 + src/include/parser/parse_node.h | 5 +- src/include/parser/parse_relation.h | 3 +- src/include/tcop/cmdtaglist.h | 1 + src/interfaces/libpq/fe-exec.c | 9 +- src/pl/plpgsql/src/pl_exec.c | 7 +- src/pl/plpgsql/src/pl_gram.y | 8 + src/pl/plpgsql/src/pl_unreserved_kwlist.h | 1 + src/pl/plpgsql/src/plpgsql.h | 2 +- src/test/isolation/expected/merge-delete.out | 117 + .../expected/merge-insert-update.out | 94 + .../expected/merge-match-recheck.out | 116 + src/test/isolation/expected/merge-update.out | 314 +++ src/test/isolation/isolation_schedule | 4 + src/test/isolation/specs/merge-delete.spec | 50 + .../isolation/specs/merge-insert-update.spec | 51 + .../isolation/specs/merge-match-recheck.spec | 77 + src/test/isolation/specs/merge-update.spec | 156 ++ src/test/regress/expected/identity.out | 54 + src/test/regress/expected/merge.out | 1934 +++++++++++++++++ src/test/regress/expected/privileges.out | 98 + src/test/regress/expected/rowsecurity.out | 182 ++ src/test/regress/expected/rules.out | 32 + src/test/regress/expected/triggers.out | 48 + src/test/regress/expected/with.out | 133 ++ src/test/regress/parallel_schedule | 2 +- src/test/regress/sql/identity.sql | 46 + src/test/regress/sql/merge.sql | 1273 +++++++++++ src/test/regress/sql/privileges.sql | 108 + src/test/regress/sql/rowsecurity.sql | 156 ++ src/test/regress/sql/rules.sql | 33 + src/test/regress/sql/triggers.sql | 47 + src/test/regress/sql/with.sql | 56 + src/tools/pgindent/typedefs.list | 4 + 95 files changed, 8726 insertions(+), 167 deletions(-) create mode 100644 doc/src/sgml/ref/merge.sgml create mode 100644 src/backend/parser/parse_merge.c create mode 100644 src/include/parser/parse_merge.h create mode 100644 src/test/isolation/expected/merge-delete.out create mode 100644 src/test/isolation/expected/merge-insert-update.out create mode 100644 src/test/isolation/expected/merge-match-recheck.out create mode 100644 src/test/isolation/expected/merge-update.out create mode 100644 src/test/isolation/specs/merge-delete.spec create mode 100644 src/test/isolation/specs/merge-insert-update.spec create mode 100644 src/test/isolation/specs/merge-match-recheck.spec create mode 100644 src/test/isolation/specs/merge-update.spec create mode 100644 src/test/regress/expected/merge.out create mode 100644 src/test/regress/sql/merge.sql diff --git a/contrib/test_decoding/expected/ddl.out b/contrib/test_decoding/expected/ddl.out index 8bb52b559f..1e37c8c897 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 ea406b1303..807bc56a45 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', 'include-sequences', '0'); +-- 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; diff --git a/doc/src/sgml/libpq.sgml b/doc/src/sgml/libpq.sgml index 3998b1781b..70233aa872 100644 --- a/doc/src/sgml/libpq.sgml +++ b/doc/src/sgml/libpq.sgml @@ -4125,9 +4125,11 @@ char *PQcmdTuples(PGresult *res); PGresult. This function can only be used following the execution of a SELECT, CREATE TABLE AS, INSERT, UPDATE, DELETE, - MOVE, FETCH, or COPY statement, - or an EXECUTE of a prepared query that contains an - INSERT, UPDATE, or DELETE statement. + MERGE, MOVE, FETCH, + or COPY statement, or an EXECUTE of a + prepared query that contains an INSERT, + UPDATE, DELETE, + or MERGE statement. If the command that generated the PGresult was anything else, returns an empty string. The caller should not free the return value directly. It will be freed when diff --git a/doc/src/sgml/mvcc.sgml b/doc/src/sgml/mvcc.sgml index b4d1e57170..905460723c 100644 --- a/doc/src/sgml/mvcc.sgml +++ b/doc/src/sgml/mvcc.sgml @@ -422,6 +422,37 @@ COMMIT; 11, which no longer matches the criteria. + + MERGE allows the user to specify various + combinations of INSERT, UPDATE + or DELETE subcommands. A MERGE + command with both INSERT and UPDATE + subcommands looks similar to INSERT with an + ON CONFLICT DO UPDATE clause but does not + guarantee that either INSERT or + UPDATE will occur. + If MERGE attempts an UPDATE or + DELETE and the row is concurrently updated but + the join condition still passes for the current target and the + current source tuple, then MERGE will behave + the same as the UPDATE or + DELETE commands and perform its action on the + updated version of the row. However, because MERGE + can specify several actions and they can be conditional, the + conditions for each action are re-evaluated on the updated version of + the row, starting from the first action, even if the action that had + originally matched appears later in the list of actions. + On the other hand, if the row is concurrently updated or deleted so + that the join condition fails, then MERGE will + evaluate the condition's NOT MATCHED actions next, + and execute the first one that succeeds. + If MERGE attempts an INSERT + and a unique index is present and a duplicate row is concurrently + inserted, then a uniqueness violation is raised. + MERGE does not attempt to avoid the + error by executing an UPDATE. + + Because Read Committed mode starts each command with a new snapshot that includes all transactions committed up to that instant, @@ -924,7 +955,8 @@ ERROR: could not serialize access due to read/write dependencies among transact The commands UPDATE, - DELETE, and INSERT + DELETE, INSERT, and + MERGE acquire this lock mode on the target table (in addition to ACCESS SHARE locks on any other referenced tables). In general, this lock mode will be acquired by any diff --git a/doc/src/sgml/plpgsql.sgml b/doc/src/sgml/plpgsql.sgml index e5c1356d8c..7ebc6593f1 100644 --- a/doc/src/sgml/plpgsql.sgml +++ b/doc/src/sgml/plpgsql.sgml @@ -1388,7 +1388,7 @@ EXECUTE format('SELECT count(*) FROM %I ' Another restriction on parameter symbols is that they only work in optimizable SQL commands (SELECT, INSERT, UPDATE, - DELETE, and certain commands containing one of these). + DELETE, MERGE, and certain commands containing one of these). In other statement types (generically called utility statements), you must insert values textually even if they are just data values. @@ -1666,7 +1666,8 @@ GET DIAGNOSTICS integer_var = ROW_COUNT; - UPDATE, INSERT, and DELETE + UPDATE, INSERT, DELETE, + and MERGE statements set FOUND true if at least one row is affected, false if no row is affected. diff --git a/doc/src/sgml/ref/allfiles.sgml b/doc/src/sgml/ref/allfiles.sgml index d67270ccc3..e90a0e1f83 100644 --- a/doc/src/sgml/ref/allfiles.sgml +++ b/doc/src/sgml/ref/allfiles.sgml @@ -158,6 +158,7 @@ Complete list of usable sgml source files in this directory. + diff --git a/doc/src/sgml/ref/create_policy.sgml b/doc/src/sgml/ref/create_policy.sgml index f898b7a218..e76c342d3d 100644 --- a/doc/src/sgml/ref/create_policy.sgml +++ b/doc/src/sgml/ref/create_policy.sgml @@ -55,7 +55,8 @@ CREATE POLICY name ON - For INSERT and UPDATE statements, + For INSERT, UPDATE, and + MERGE statements, WITH CHECK expressions are enforced after BEFORE triggers are fired, and before any actual data modifications are made. Thus a BEFORE ROW trigger may @@ -281,7 +282,9 @@ CREATE POLICY name ON Using INSERT for a policy means that it will apply - to INSERT commands. Rows being inserted that do + to INSERT commands and MERGE + commands that contain INSERT actions. + Rows being inserted that do not pass this policy will result in a policy violation error, and the entire INSERT command will be aborted. An INSERT policy cannot have @@ -305,7 +308,9 @@ CREATE POLICY name ON UPDATE, SELECT FOR UPDATE and SELECT FOR SHARE commands, as well as auxiliary ON CONFLICT DO UPDATE clauses of - INSERT commands. Since UPDATE + INSERT commands. + MERGE commands containing UPDATE + actions are affected as well. Since UPDATE involves pulling an existing record and replacing it with a new modified record, UPDATE policies accept both a USING expression and @@ -435,7 +440,7 @@ CREATE POLICY name ON - INSERT + INSERT / MERGE ... THEN INSERT New row @@ -459,7 +464,7 @@ CREATE POLICY name ON - UPDATE + UPDATE / MERGE ... THEN UPDATE Existing & new rows @@ -613,6 +618,14 @@ AND (see CREATE VIEW). + + No separate policy exists for MERGE. Instead, the policies + defined for SELECT, INSERT, + UPDATE, and DELETE are applied + while executing MERGE, depending on the actions that are + performed. + + Additional discussion and practical examples can be found in . diff --git a/doc/src/sgml/ref/insert.sgml b/doc/src/sgml/ref/insert.sgml index 2973b72b81..a9af9959c0 100644 --- a/doc/src/sgml/ref/insert.sgml +++ b/doc/src/sgml/ref/insert.sgml @@ -589,6 +589,13 @@ INSERT oid count + + + You may also wish to consider using MERGE, since that + allows mixing INSERT, UPDATE, and + DELETE within a single statement. + See . + @@ -759,7 +766,9 @@ INSERT INTO distributors (did, dname) VALUES (10, 'Conrad International') Also, the case in which a column name list is omitted, but not all the columns are filled from the VALUES clause or query, - is disallowed by the standard. + is disallowed by the standard. If you prefer a more SQL standard + conforming statement than ON CONFLICT, see + . diff --git a/doc/src/sgml/ref/merge.sgml b/doc/src/sgml/ref/merge.sgml new file mode 100644 index 0000000000..c547122c9b --- /dev/null +++ b/doc/src/sgml/ref/merge.sgml @@ -0,0 +1,620 @@ + + + + + + MERGE + 7 + SQL - Language Statements + + + + MERGE + conditionally insert, update, or delete rows of a table + + + + +[ WITH with_query [, ...] ] +MERGE INTO target_table_name [ [ AS ] target_alias ] +USING data_source ON join_condition +when_clause [...] + +where data_source is + +{ source_table_name | ( source_query ) } [ [ AS ] source_alias ] + +and when_clause is + +{ WHEN MATCHED [ AND condition ] THEN { merge_update | merge_delete | DO NOTHING } | + WHEN NOT MATCHED [ AND condition ] THEN { merge_insert | DO NOTHING } } + +and merge_insert is + +INSERT [( column_name [, ...] )] +[ OVERRIDING { SYSTEM | USER } VALUE ] +{ VALUES ( { expression | DEFAULT } [, ...] ) | DEFAULT VALUES } + +and merge_update is + +UPDATE SET { column_name = { expression | DEFAULT } | + ( column_name [, ...] ) = ( { expression | DEFAULT } [, ...] ) } [, ...] + +and merge_delete is + +DELETE + + + + + Description + + + MERGE performs actions that modify rows in the + target_table_name, + using the data_source. + MERGE provides a single SQL + statement that can conditionally INSERT, + UPDATE or DELETE rows, a task + that would otherwise require multiple procedural language statements. + + + + First, the MERGE command performs a join + from data_source to + target_table_name + producing zero or more candidate change rows. For each candidate change + row, the status of MATCHED or NOT MATCHED + is set just once, after which WHEN clauses are evaluated + in the order specified. For each candidate change row, the first clause to + evaluate as true is executed. No more than one WHEN + clause is executed for any candidate change row. + + + + MERGE actions have the same effect as + regular UPDATE, INSERT, or + DELETE commands of the same names. The syntax of + those commands is different, notably that there is no WHERE + clause and no table name is specified. All actions refer to the + target_table_name, + though modifications to other tables may be made using triggers. + + + + When DO NOTHING is specified, the source row is + skipped. Since actions are evaluated in their specified order, DO + NOTHING can be handy to skip non-interesting source rows before + more fine-grained handling. + + + + There is no separate MERGE privilege. + If you specify an update action, you must have the + UPDATE privilege on the column(s) + of the target_table_name + that are referred to in the SET clause. + If you specify an insert action, you must have the INSERT + privilege on the target_table_name. + If you specify an delete action, you must have the DELETE + privilege on the target_table_name. + Privileges are tested once at statement start and are checked + whether or not particular WHEN clauses are executed. + You will require the SELECT privilege on the + data_source and any column(s) + of the target_table_name + referred to in a condition. + + + + MERGE is not supported if the + target_table_name is a + materialized view, foreign table, or if it has any + rules defined on it. + + + + + Parameters + + + + target_table_name + + + The name (optionally schema-qualified) of the target table to merge into. + + + + + + target_alias + + + A substitute name for the target table. When an alias is + provided, it completely hides the actual name of the table. For + example, given MERGE INTO foo AS f, the remainder of the + MERGE statement must refer to this table as + f not foo. + + + + + + source_table_name + + + The name (optionally schema-qualified) of the source table, view, or + transition table. + + + + + + source_query + + + A query (SELECT statement or VALUES + statement) that supplies the rows to be merged into the + target_table_name. + Refer to the + statement or + statement for a description of the syntax. + + + + + + source_alias + + + A substitute name for the data source. When an alias is + provided, it completely hides the actual name of the table or the fact + that a query was issued. + + + + + + join_condition + + + join_condition is + an expression resulting in a value of type + boolean (similar to a WHERE + clause) that specifies which rows in the + data_source + match rows in the + target_table_name. + + + + Only columns from target_table_name + that attempt to match data_source + rows should appear in join_condition. + join_condition subexpressions that + only reference target_table_name + columns can affect which action is taken, often in surprising ways. + + + + + + + when_clause + + + At least one WHEN clause is required. + + + If the WHEN clause specifies WHEN MATCHED + and the candidate change row matches a row in the + target_table_name, + the WHEN clause is executed if the + condition is + absent or it evaluates to true. + + + Conversely, if the WHEN clause specifies + WHEN NOT MATCHED + and the candidate change row does not match a row in the + target_table_name, + the WHEN clause is executed if the + condition is + absent or it evaluates to true. + + + + + + condition + + + An expression that returns a value of type boolean. + If this expression for a WHEN clause + returns true, then the action for that clause + is executed for that row. + + + A condition on a WHEN MATCHED clause can refer to columns + in both the source and the target relations. A condition on a + WHEN NOT MATCHED clause can only refer to columns from + the source relation, since by definition there is no matching target row. + Only the system attributes from the target table are accessible. + + + + + + merge_insert + + + The specification of an INSERT action that inserts + one row into the target table. + The target column names can be listed in any order. If no list of + column names is given at all, the default is all the columns of the + table in their declared order. + + + Each column not present in the explicit or implicit column list will be + filled with a default value, either its declared default value + or null if there is none. + + + If the expression for any column is not of the correct data type, + automatic type conversion will be attempted. + + + If target_table_name + is a partitioned table, each row is routed to the appropriate partition + and inserted into it. + If target_table_name + is a partition, an error will occur if any input row violates the + partition constraint. + + + Column names may not be specified more than once. + INSERT actions cannot contain sub-selects. + + + Only one VALUES clause can be specified. + The VALUES clause can only refer to columns from + the source relation, since by definition there is no matching target row. + + + + + + merge_update + + + The specification of an UPDATE action that updates + the current row of the target_table_name. + Column names may not be specified more than once. + + + Neither a table name nor a WHERE clause are allowed. + + + + + + merge_delete + + + Specifies a DELETE action that deletes the current row + of the target_table_name. + Do not include the table name or any other clauses, as you would normally + do with a command. + + + + + + column_name + + + The name of a column in the target_table_name. The column name + can be qualified with a subfield name or array subscript, if + needed. (Inserting into only some fields of a composite + column leaves the other fields null.) + Do not include the table's name in the specification + of a target column. + + + + + + OVERRIDING SYSTEM VALUE + + + Without this clause, it is an error to specify an explicit value + (other than DEFAULT) for an identity column defined + as GENERATED ALWAYS. This clause overrides that + restriction. + + + + + + OVERRIDING USER VALUE + + + If this clause is specified, then any values supplied for identity + columns defined as GENERATED BY DEFAULT are ignored + and the default sequence-generated values are applied. + + + + + + DEFAULT VALUES + + + All columns will be filled with their default values. + (An OVERRIDING clause is not permitted in this + form.) + + + + + + expression + + + An expression to assign to the column. If used in a + WHEN MATCHED clause, the expression can use values + from the original row in the target table, and values from the + data_source row. + If used in a WHEN NOT MATCHED clause, the + expression can use values from the data_source. + + + + + + DEFAULT + + + Set the column to its default value (which will be NULL + if no specific default expression has been assigned to it). + + + + + + with_query + + + The WITH clause allows you to specify one or more + subqueries that can be referenced by name in the MERGE + query. See and + for details. + + + + + + + + + Outputs + + + On successful completion, a MERGE command returns a command + tag of the form + +MERGE total_count + + The total_count is the total + number of rows changed (whether inserted, updated, or deleted). + If total_count is 0, no rows + were changed in any way. + + + + + + Notes + + + The following steps take place during the execution of + MERGE. + + + + Perform any BEFORE STATEMENT triggers for all + actions specified, whether or not their WHEN + clauses match. + + + + + Perform a join from source to target table. + The resulting query will be optimized normally and will produce + a set of candidate change rows. For each candidate change row, + + + + Evaluate whether each row is MATCHED or + NOT MATCHED. + + + + + Test each WHEN condition in the order + specified until one returns true. + + + + + When a condition returns true, perform the following actions: + + + + Perform any BEFORE ROW triggers that fire + for the action's event type. + + + + + Perform the specified action, invoking any check constraints on the + target table. + + + + + Perform any AFTER ROW triggers that fire for + the action's event type. + + + + + + + + + + + Perform any AFTER STATEMENT triggers for actions + specified, whether or not they actually occur. This is similar to the + behavior of an UPDATE statement that modifies no rows. + + + + In summary, statement triggers for an event type (say, + INSERT) will be fired whenever we + specify an action of that kind. + In contrast, row-level triggers will fire only for the specific event type + being executed. + So a MERGE command might fire statement triggers for both + UPDATE and INSERT, even though only + UPDATE row triggers were fired. + + + + You should ensure that the join produces at most one candidate change row + for each target row. In other words, a target row shouldn't join to more + than one data source row. If it does, then only one of the candidate change + rows will be used to modify the target row; later attempts to modify the + row will cause an error. + This can also occur if row triggers make changes to the target table + and the rows so modified are then subsequently also modified by + MERGE. + If the repeated action is an INSERT, this will + cause a uniqueness violation, while a repeated UPDATE + or DELETE will cause a cardinality violation; the + latter behavior is required by the SQL standard. + This differs from historical PostgreSQL + behavior of joins in UPDATE and + DELETE statements where second and subsequent + attempts to modify the same row are simply ignored. + + + + If a WHEN clause omits an AND + sub-clause, it becomes the final reachable clause of that + kind (MATCHED or NOT MATCHED). + If a later WHEN clause of that kind + is specified it would be provably unreachable and an error is raised. + If no final reachable clause is specified of either kind, it is + possible that no action will be taken for a candidate change row. + + + + The order in which rows are generated from the data source is + indeterminate by default. + A source_query can be + used to specify a consistent ordering, if required, which might be + needed to avoid deadlocks between concurrent transactions. + + + + There is no RETURNING clause with + MERGE. Actions of INSERT, + UPDATE and DELETE cannot contain + RETURNING or WITH clauses. + + + + You may also wish to consider using INSERT ... ON CONFLICT + as an alternative statement which offers the ability to run an + UPDATE if a concurrent INSERT + occurs. There are a variety of differences and restrictions between + the two statement types and they are not interchangeable. + + + + + Examples + + + Perform maintenance on CustomerAccounts based + upon new Transactions. + + +MERGE INTO CustomerAccount CA +USING RecentTransactions T +ON T.CustomerId = CA.CustomerId +WHEN MATCHED THEN + UPDATE SET Balance = Balance + TransactionValue +WHEN NOT MATCHED THEN + INSERT (CustomerId, Balance) + VALUES (T.CustomerId, T.TransactionValue); + + + + + Notice that this would be exactly equivalent to the following + statement because the MATCHED result does not change + during execution. + + +MERGE INTO CustomerAccount CA +USING (Select CustomerId, TransactionValue From RecentTransactions) AS T +ON CA.CustomerId = T.CustomerId +WHEN NOT MATCHED THEN + INSERT (CustomerId, Balance) + VALUES (T.CustomerId, T.TransactionValue) +WHEN MATCHED THEN + UPDATE SET Balance = Balance + TransactionValue; + + + + + Attempt to insert a new stock item along with the quantity of stock. If + the item already exists, instead update the stock count of the existing + item. Don't allow entries that have zero stock. + +MERGE INTO wines w +USING wine_stock_changes s +ON s.winename = w.winename +WHEN NOT MATCHED AND s.stock_delta > 0 THEN + INSERT VALUES(s.winename, s.stock_delta) +WHEN MATCHED AND w.stock + s.stock_delta > 0 THEN + UPDATE SET stock = w.stock + s.stock_delta; +WHEN MATCHED THEN + DELETE; + + + The wine_stock_changes table might be, for example, a + temporary table recently loaded into the database. + + + + + + Compatibility + + This command conforms to the SQL standard. + + + The WITH clause and DO NOTHING action are extensions to + the SQL standard. + + + diff --git a/doc/src/sgml/reference.sgml b/doc/src/sgml/reference.sgml index da421ff24e..a3b743e8c1 100644 --- a/doc/src/sgml/reference.sgml +++ b/doc/src/sgml/reference.sgml @@ -186,6 +186,7 @@ &listen; &load; &lock; + &merge; &move; ¬ify; &prepare; diff --git a/doc/src/sgml/trigger.sgml b/doc/src/sgml/trigger.sgml index 7e2654493b..04e702a795 100644 --- a/doc/src/sgml/trigger.sgml +++ b/doc/src/sgml/trigger.sgml @@ -192,6 +192,28 @@ will be fired. + + No separate triggers are defined for MERGE. Instead, + statement-level or row-level UPDATE, + DELETE, and INSERT triggers are fired + depending on (for statement-level triggers) what actions are specified in + the MERGE query and (for row-level triggers) what + actions are performed. + + + + While running a MERGE command, statement-level + BEFORE and AFTER triggers are + fired for events specified in the actions of the MERGE + command, irrespective of whether or not the action is ultimately performed. + This is the same as an UPDATE statement that updates + no rows, yet statement-level triggers are fired. + The row-level triggers are fired only when a row is actually updated, + inserted or deleted. So it's perfectly legal that while statement-level + triggers are fired for certain types of action, no row-level triggers + are fired for the same kind of action. + + Trigger functions invoked by per-statement triggers should always return NULL. Trigger functions invoked by per-row diff --git a/src/backend/catalog/sql_features.txt b/src/backend/catalog/sql_features.txt index 097d9c4784..4c3e29111d 100644 --- a/src/backend/catalog/sql_features.txt +++ b/src/backend/catalog/sql_features.txt @@ -240,9 +240,9 @@ F311 Schema definition statement 02 CREATE TABLE for persistent base tables YES F311 Schema definition statement 03 CREATE VIEW YES F311 Schema definition statement 04 CREATE VIEW: WITH CHECK OPTION YES F311 Schema definition statement 05 GRANT statement YES -F312 MERGE statement NO consider INSERT ... ON CONFLICT DO UPDATE -F313 Enhanced MERGE statement NO -F314 MERGE statement with DELETE branch NO +F312 MERGE statement YES +F313 Enhanced MERGE statement YES +F314 MERGE statement with DELETE branch YES F321 User authorization YES F341 Usage tables YES F361 Subprogram support YES diff --git a/src/backend/commands/explain.c b/src/backend/commands/explain.c index 9f632285b6..cb13227db1 100644 --- a/src/backend/commands/explain.c +++ b/src/backend/commands/explain.c @@ -1188,6 +1188,9 @@ ExplainNode(PlanState *planstate, List *ancestors, case CMD_DELETE: pname = operation = "Delete"; break; + case CMD_MERGE: + pname = operation = "Merge"; + break; default: pname = "???"; break; @@ -3877,6 +3880,11 @@ show_modifytable_info(ModifyTableState *mtstate, List *ancestors, operation = "Delete"; foperation = "Foreign Delete"; break; + case CMD_MERGE: + operation = "Merge"; + /* XXX unsupported for now, but avoid compiler noise */ + foperation = "Foreign Merge"; + break; default: operation = "???"; foperation = "Foreign ???"; @@ -3999,6 +4007,33 @@ show_modifytable_info(ModifyTableState *mtstate, List *ancestors, other_path, 0, es); } } + else if (node->operation == CMD_MERGE) + { + /* EXPLAIN ANALYZE display of tuples processed */ + if (es->analyze && mtstate->ps.instrument) + { + double total; + double insert_path; + double update_path; + double delete_path; + double skipped_path; + + InstrEndLoop(outerPlanState(mtstate)->instrument); + + /* count the number of source rows */ + total = outerPlanState(mtstate)->instrument->ntuples; + insert_path = mtstate->mt_merge_inserted; + update_path = mtstate->mt_merge_updated; + delete_path = mtstate->mt_merge_deleted; + skipped_path = total - insert_path - update_path - delete_path; + Assert(skipped_path >= 0); + + ExplainPropertyFloat("Tuples Inserted", NULL, insert_path, 0, es); + ExplainPropertyFloat("Tuples Updated", NULL, update_path, 0, es); + ExplainPropertyFloat("Tuples Deleted", NULL, delete_path, 0, es); + ExplainPropertyFloat("Tuples Skipped", NULL, skipped_path, 0, es); + } + } if (labeltargets) ExplainCloseGroup("Target Tables", "Target Tables", false, es); diff --git a/src/backend/commands/trigger.c b/src/backend/commands/trigger.c index fce79b02a5..13cb516752 100644 --- a/src/backend/commands/trigger.c +++ b/src/backend/commands/trigger.c @@ -84,7 +84,8 @@ static bool GetTupleForTrigger(EState *estate, ItemPointer tid, LockTupleMode lockmode, TupleTableSlot *oldslot, - TupleTableSlot **newSlot); + TupleTableSlot **newSlot, + TM_FailureData *tmfpd); static bool TriggerEnabled(EState *estate, ResultRelInfo *relinfo, Trigger *trigger, TriggerEvent event, Bitmapset *modifiedCols, @@ -2713,7 +2714,8 @@ ExecBRDeleteTriggers(EState *estate, EPQState *epqstate, TupleTableSlot *epqslot_candidate = NULL; if (!GetTupleForTrigger(estate, epqstate, relinfo, tupleid, - LockTupleExclusive, slot, &epqslot_candidate)) + LockTupleExclusive, slot, &epqslot_candidate, + NULL)) return false; /* @@ -2728,7 +2730,6 @@ ExecBRDeleteTriggers(EState *estate, EPQState *epqstate, } trigtuple = ExecFetchSlotHeapTuple(slot, true, &should_free); - } else { @@ -2804,6 +2805,7 @@ ExecARDeleteTriggers(EState *estate, tupleid, LockTupleExclusive, slot, + NULL, NULL); else ExecForceStoreHeapTuple(fdw_trigtuple, slot, false); @@ -2944,7 +2946,8 @@ ExecBRUpdateTriggers(EState *estate, EPQState *epqstate, ResultRelInfo *relinfo, ItemPointer tupleid, HeapTuple fdw_trigtuple, - TupleTableSlot *newslot) + TupleTableSlot *newslot, + TM_FailureData *tmfd) { TriggerDesc *trigdesc = relinfo->ri_TrigDesc; TupleTableSlot *oldslot = ExecGetTriggerOldSlot(estate, relinfo); @@ -2967,7 +2970,8 @@ ExecBRUpdateTriggers(EState *estate, EPQState *epqstate, /* get a copy of the on-disk tuple we are planning to update */ if (!GetTupleForTrigger(estate, epqstate, relinfo, tupleid, - lockmode, oldslot, &epqslot_candidate)) + lockmode, oldslot, &epqslot_candidate, + tmfd)) return false; /* cancel the update action */ /* @@ -3121,6 +3125,7 @@ ExecARUpdateTriggers(EState *estate, ResultRelInfo *relinfo, tupleid, LockTupleExclusive, oldslot, + NULL, NULL); else if (fdw_trigtuple != NULL) ExecForceStoreHeapTuple(fdw_trigtuple, oldslot, false); @@ -3275,7 +3280,8 @@ GetTupleForTrigger(EState *estate, ItemPointer tid, LockTupleMode lockmode, TupleTableSlot *oldslot, - TupleTableSlot **epqslot) + TupleTableSlot **epqslot, + TM_FailureData *tmfdp) { Relation relation = relinfo->ri_RelationDesc; @@ -3301,6 +3307,10 @@ GetTupleForTrigger(EState *estate, lockflags, &tmfd); + /* Let the caller know about the status of this operation */ + if (tmfdp) + *tmfdp = tmfd; + switch (test) { case TM_SelfModified: @@ -3821,8 +3831,23 @@ struct AfterTriggersTableData bool before_trig_done; /* did we already queue BS triggers? */ bool after_trig_done; /* did we already queue AS triggers? */ AfterTriggerEventList after_trig_events; /* if so, saved list pointer */ - Tuplestorestate *old_tuplestore; /* "old" transition table, if any */ - Tuplestorestate *new_tuplestore; /* "new" transition table, if any */ + + /* + * We maintain separate transition tables for UPDATE/INSERT/DELETE since + * MERGE can run all three actions in a single statement. Note that UPDATE + * needs both old and new transition tables whereas INSERT needs only new, + * and DELETE needs only old. + */ + + /* "old" transition table for UPDATE, if any */ + Tuplestorestate *old_upd_tuplestore; + /* "new" transition table for UPDATE, if any */ + Tuplestorestate *new_upd_tuplestore; + /* "old" transition table for DELETE, if any */ + Tuplestorestate *old_del_tuplestore; + /* "new" transition table for INSERT, if any */ + Tuplestorestate *new_ins_tuplestore; + TupleTableSlot *storeslot; /* for converting to tuplestore's format */ }; @@ -4374,13 +4399,19 @@ AfterTriggerExecute(EState *estate, { if (LocTriggerData.tg_trigger->tgoldtable) { - LocTriggerData.tg_oldtable = evtshared->ats_table->old_tuplestore; + if (TRIGGER_FIRED_BY_UPDATE(evtshared->ats_event)) + LocTriggerData.tg_oldtable = evtshared->ats_table->old_upd_tuplestore; + else + LocTriggerData.tg_oldtable = evtshared->ats_table->old_del_tuplestore; evtshared->ats_table->closed = true; } if (LocTriggerData.tg_trigger->tgnewtable) { - LocTriggerData.tg_newtable = evtshared->ats_table->new_tuplestore; + if (TRIGGER_FIRED_BY_INSERT(evtshared->ats_event)) + LocTriggerData.tg_newtable = evtshared->ats_table->new_ins_tuplestore; + else + LocTriggerData.tg_newtable = evtshared->ats_table->new_upd_tuplestore; evtshared->ats_table->closed = true; } } @@ -4794,8 +4825,10 @@ TransitionCaptureState * MakeTransitionCaptureState(TriggerDesc *trigdesc, Oid relid, CmdType cmdType) { TransitionCaptureState *state; - bool need_old, - need_new; + bool need_old_upd, + need_new_upd, + need_old_del, + need_new_ins; AfterTriggersTableData *table; MemoryContext oldcxt; ResourceOwner saveResourceOwner; @@ -4807,23 +4840,31 @@ MakeTransitionCaptureState(TriggerDesc *trigdesc, Oid relid, CmdType cmdType) switch (cmdType) { case CMD_INSERT: - need_old = false; - need_new = trigdesc->trig_insert_new_table; + need_old_upd = need_old_del = need_new_upd = false; + need_new_ins = trigdesc->trig_insert_new_table; break; case CMD_UPDATE: - need_old = trigdesc->trig_update_old_table; - need_new = trigdesc->trig_update_new_table; + need_old_upd = trigdesc->trig_update_old_table; + need_new_upd = trigdesc->trig_update_new_table; + need_old_del = need_new_ins = false; break; case CMD_DELETE: - need_old = trigdesc->trig_delete_old_table; - need_new = false; + need_old_del = trigdesc->trig_delete_old_table; + need_old_upd = need_new_upd = need_new_ins = false; + break; + case CMD_MERGE: + need_old_upd = trigdesc->trig_update_old_table; + need_new_upd = trigdesc->trig_update_new_table; + need_old_del = trigdesc->trig_delete_old_table; + need_new_ins = trigdesc->trig_insert_new_table; break; default: elog(ERROR, "unexpected CmdType: %d", (int) cmdType); - need_old = need_new = false; /* keep compiler quiet */ + /* keep compiler quiet */ + need_old_upd = need_new_upd = need_old_del = need_new_ins = false; break; } - if (!need_old && !need_new) + if (!need_old_upd && !need_new_upd && !need_new_ins && !need_old_del) return NULL; /* Check state, like AfterTriggerSaveEvent. */ @@ -4853,10 +4894,14 @@ MakeTransitionCaptureState(TriggerDesc *trigdesc, Oid relid, CmdType cmdType) saveResourceOwner = CurrentResourceOwner; CurrentResourceOwner = CurTransactionResourceOwner; - if (need_old && table->old_tuplestore == NULL) - table->old_tuplestore = tuplestore_begin_heap(false, false, work_mem); - if (need_new && table->new_tuplestore == NULL) - table->new_tuplestore = tuplestore_begin_heap(false, false, work_mem); + if (need_old_upd && table->old_upd_tuplestore == NULL) + table->old_upd_tuplestore = tuplestore_begin_heap(false, false, work_mem); + if (need_new_upd && table->new_upd_tuplestore == NULL) + table->new_upd_tuplestore = tuplestore_begin_heap(false, false, work_mem); + if (need_old_del && table->old_del_tuplestore == NULL) + table->old_del_tuplestore = tuplestore_begin_heap(false, false, work_mem); + if (need_new_ins && table->new_ins_tuplestore == NULL) + table->new_ins_tuplestore = tuplestore_begin_heap(false, false, work_mem); CurrentResourceOwner = saveResourceOwner; MemoryContextSwitchTo(oldcxt); @@ -5045,12 +5090,20 @@ AfterTriggerFreeQuery(AfterTriggersQueryData *qs) { AfterTriggersTableData *table = (AfterTriggersTableData *) lfirst(lc); - ts = table->old_tuplestore; - table->old_tuplestore = NULL; + ts = table->old_upd_tuplestore; + table->old_upd_tuplestore = NULL; if (ts) tuplestore_end(ts); - ts = table->new_tuplestore; - table->new_tuplestore = NULL; + ts = table->new_upd_tuplestore; + table->new_upd_tuplestore = NULL; + if (ts) + tuplestore_end(ts); + ts = table->old_del_tuplestore; + table->old_del_tuplestore = NULL; + if (ts) + tuplestore_end(ts); + ts = table->new_ins_tuplestore; + table->new_ins_tuplestore = NULL; if (ts) tuplestore_end(ts); if (table->storeslot) @@ -5356,17 +5409,17 @@ GetAfterTriggersTransitionTable(int event, { Assert(TupIsNull(newslot)); if (event == TRIGGER_EVENT_DELETE && delete_old_table) - tuplestore = transition_capture->tcs_private->old_tuplestore; + tuplestore = transition_capture->tcs_private->old_del_tuplestore; else if (event == TRIGGER_EVENT_UPDATE && update_old_table) - tuplestore = transition_capture->tcs_private->old_tuplestore; + tuplestore = transition_capture->tcs_private->old_upd_tuplestore; } else if (!TupIsNull(newslot)) { Assert(TupIsNull(oldslot)); if (event == TRIGGER_EVENT_INSERT && insert_new_table) - tuplestore = transition_capture->tcs_private->new_tuplestore; + tuplestore = transition_capture->tcs_private->new_ins_tuplestore; else if (event == TRIGGER_EVENT_UPDATE && update_new_table) - tuplestore = transition_capture->tcs_private->new_tuplestore; + tuplestore = transition_capture->tcs_private->new_upd_tuplestore; } return tuplestore; @@ -5980,6 +6033,7 @@ AfterTriggerSaveEvent(EState *estate, ResultRelInfo *relinfo, */ if (row_trigger && transition_capture != NULL) { + TupleTableSlot *original_insert_tuple = transition_capture->tcs_original_insert_tuple; /* * Capture the old tuple in the appropriate transition table based on @@ -6010,17 +6064,15 @@ AfterTriggerSaveEvent(EState *estate, ResultRelInfo *relinfo, newslot, transition_capture); TransitionTableAddTuple(estate, transition_capture, relinfo, - newslot, - transition_capture->tcs_original_insert_tuple, - new_tuplestore); + newslot, original_insert_tuple, new_tuplestore); } /* * If transition tables are the only reason we're here, return. As * mentioned above, we can also be here during update tuple routing in * presence of transition tables, in which case this function is - * called separately for oldtup and newtup, so we expect exactly one - * of them to be NULL. + * called separately for OLD and NEW, so we expect exactly one of them + * to be NULL. */ if (trigdesc == NULL || (event == TRIGGER_EVENT_DELETE && !trigdesc->trig_delete_after_row) || diff --git a/src/backend/executor/README b/src/backend/executor/README index bf5e70860d..0b5183fc4a 100644 --- a/src/backend/executor/README +++ b/src/backend/executor/README @@ -39,7 +39,7 @@ columns, combine the values into a new row, and apply the update. (For a heap table, the row-identity junk column is a CTID, but other things may be used for other table types.) For DELETE, the plan tree need only deliver junk row-identity column(s), and the ModifyTable node visits each of those -rows and marks the row deleted. +rows and marks the row deleted. MERGE is described below. XXX a great deal more documentation needs to be written here... @@ -223,6 +223,45 @@ fast-path step types (EEOP_ASSIGN_*_VAR) to handle targetlist entries that are simple Vars using only one step instead of two. +MERGE +----- + +MERGE is a multiple-table, multiple-action command: It specifies a target +table and a source relation, and can contain multiple WHEN MATCHED and +WHEN NOT MATCHED clauses, each of which specifies one UPDATE, INSERT, +UPDATE, or DO NOTHING actions. The target table is modified by MERGE, +and the source relation supplies additional data for the actions. Each action +optionally specifies a qualifying expression that is evaluated for each tuple. + +In the planner, transform_MERGE_to_join constructs a join between the target +table and the source relation, with row-identifying junk columns from the target +table. This join is an outer join if the MERGE command contains any WHEN NOT +MATCHED clauses; the ModifyTable node fetches tuples from the plan tree of that +join. If the row-identifying columns in the fetched tuple are NULL, then the +source relation contains a tuple that is not matched by any tuples in the +target table, so the qualifying expression for each WHEN NOT MATCHED clause is +evaluated given that tuple as returned by the plan. If the expression returns +true, the action indicated by the clause is executed, and no further clauses +are evaluated. On the other hand, if the row-identifying columns are not +NULL, then the matching tuple from the target table can be fetched; qualifying +expression of each WHEN MATCHED clause is evaluated given both the fetched +tuple and the tuple returned by the plan. + +If no WHEN NOT MATCHED clauses are present, then the join constructed by +the planner is an inner join, and the row-identifying junk columns are +always non NULL. + +If WHEN MATCHED ends up processing a row that is concurrently updated or deleted, +EvalPlanQual (see below) is used to find the latest version of the row, and +that is re-fetched; if it exists, the search for a matching WHEN MATCHED clause +to use starts at the top. + +MERGE does not allow its own type of triggers, but instead fires UPDATE, DELETE, +and INSERT triggers: row triggers are fired for each row when an action is +executed for that row. Statement triggers are fired always, regardless of +whether any rows match the corresponding clauses. + + Memory Management ----------------- diff --git a/src/backend/executor/execMain.c b/src/backend/executor/execMain.c index 473d2e00a2..ef2fd46092 100644 --- a/src/backend/executor/execMain.c +++ b/src/backend/executor/execMain.c @@ -233,6 +233,7 @@ standard_ExecutorStart(QueryDesc *queryDesc, int eflags) case CMD_INSERT: case CMD_DELETE: case CMD_UPDATE: + case CMD_MERGE: estate->es_output_cid = GetCurrentCommandId(true); break; @@ -1244,6 +1245,8 @@ InitResultRelInfo(ResultRelInfo *resultRelInfo, resultRelInfo->ri_ReturningSlot = NULL; resultRelInfo->ri_TrigOldSlot = NULL; resultRelInfo->ri_TrigNewSlot = NULL; + resultRelInfo->ri_matchedMergeAction = NIL; + resultRelInfo->ri_notMatchedMergeAction = NIL; /* * Only ExecInitPartitionInfo() and ExecInitPartitionDispatchInfo() pass @@ -2142,6 +2145,19 @@ ExecWithCheckOptions(WCOKind kind, ResultRelInfo *resultRelInfo, errmsg("new row violates row-level security policy for table \"%s\"", wco->relname))); break; + case WCO_RLS_MERGE_UPDATE_CHECK: + case WCO_RLS_MERGE_DELETE_CHECK: + if (wco->polname != NULL) + ereport(ERROR, + (errcode(ERRCODE_INSUFFICIENT_PRIVILEGE), + errmsg("target row violates row-level security policy \"%s\" (USING expression) for table \"%s\"", + wco->polname, wco->relname))); + else + ereport(ERROR, + (errcode(ERRCODE_INSUFFICIENT_PRIVILEGE), + errmsg("target row violates row-level security policy (USING expression) for table \"%s\"", + wco->relname))); + break; case WCO_RLS_CONFLICT_CHECK: if (wco->polname != NULL) ereport(ERROR, diff --git a/src/backend/executor/execPartition.c b/src/backend/executor/execPartition.c index 90ed1485d1..aca42ca5b8 100644 --- a/src/backend/executor/execPartition.c +++ b/src/backend/executor/execPartition.c @@ -20,6 +20,7 @@ #include "catalog/pg_type.h" #include "executor/execPartition.h" #include "executor/executor.h" +#include "executor/nodeModifyTable.h" #include "foreign/fdwapi.h" #include "mb/pg_wchar.h" #include "miscadmin.h" @@ -182,6 +183,7 @@ static char *ExecBuildSlotPartitionKeyDescription(Relation rel, bool *isnull, int maxfieldlen); static List *adjust_partition_colnos(List *colnos, ResultRelInfo *leaf_part_rri); +static List *adjust_partition_colnos_using_map(List *colnos, AttrMap *attrMap); static void ExecInitPruningContext(PartitionPruneContext *context, List *pruning_steps, PartitionDesc partdesc, @@ -853,6 +855,99 @@ ExecInitPartitionInfo(ModifyTableState *mtstate, EState *estate, lappend(estate->es_tuple_routing_result_relations, leaf_part_rri); + /* + * Initialize information about this partition that's needed to handle + * MERGE. We take the "first" result relation's mergeActionList as + * reference and make copy for this relation, converting stuff that + * references attribute numbers to match this relation's. + * + * This duplicates much of the logic in ExecInitMerge(), so something + * changes there, look here too. + */ + if (node && node->operation == CMD_MERGE) + { + List *firstMergeActionList = linitial(node->mergeActionLists); + ListCell *lc; + ExprContext *econtext = mtstate->ps.ps_ExprContext; + + if (part_attmap == NULL) + part_attmap = + build_attrmap_by_name(RelationGetDescr(partrel), + RelationGetDescr(firstResultRel)); + + if (unlikely(!leaf_part_rri->ri_projectNewInfoValid)) + ExecInitMergeTupleSlots(mtstate, leaf_part_rri); + + foreach(lc, firstMergeActionList) + { + /* Make a copy for this relation to be safe. */ + MergeAction *action = copyObject(lfirst(lc)); + MergeActionState *action_state; + List **list; + + /* Generate the action's state for this relation */ + action_state = makeNode(MergeActionState); + action_state->mas_action = action; + + /* And put the action in the appropriate list */ + if (action->matched) + list = &leaf_part_rri->ri_matchedMergeAction; + else + list = &leaf_part_rri->ri_notMatchedMergeAction; + *list = lappend(*list, action_state); + + switch (action->commandType) + { + case CMD_INSERT: + + /* + * ExecCheckPlanOutput() already done on the targetlist + * when "first" result relation initialized and it is same + * for all result relations. + */ + action_state->mas_proj = + ExecBuildProjectionInfo(action->targetList, econtext, + leaf_part_rri->ri_newTupleSlot, + &mtstate->ps, + RelationGetDescr(partrel)); + break; + case CMD_UPDATE: + + /* + * Convert updateColnos from "first" result relation + * attribute numbers to this result rel's. + */ + if (part_attmap) + action->updateColnos = + adjust_partition_colnos_using_map(action->updateColnos, + part_attmap); + action_state->mas_proj = + ExecBuildUpdateProjection(action->targetList, + true, + action->updateColnos, + RelationGetDescr(leaf_part_rri->ri_RelationDesc), + econtext, + leaf_part_rri->ri_newTupleSlot, + NULL); + break; + case CMD_DELETE: + break; + + default: + elog(ERROR, "unknown action in MERGE WHEN clause"); + } + + /* found_whole_row intentionally ignored. */ + action->qual = + map_variable_attnos(action->qual, + firstVarno, 0, + part_attmap, + RelationGetForm(partrel)->reltype, + &found_whole_row); + action_state->mas_whenqual = + ExecInitQual((List *) action->qual, &mtstate->ps); + } + } MemoryContextSwitchTo(oldcxt); return leaf_part_rri; @@ -1433,13 +1528,23 @@ ExecBuildSlotPartitionKeyDescription(Relation rel, static List * adjust_partition_colnos(List *colnos, ResultRelInfo *leaf_part_rri) { - List *new_colnos = NIL; TupleConversionMap *map = ExecGetChildToRootMap(leaf_part_rri); - AttrMap *attrMap; + + return adjust_partition_colnos_using_map(colnos, map->attrMap); +} + +/* + * adjust_partition_colnos_using_map + * Like adjust_partition_colnos, but uses a caller-supplied map instead + * of assuming to map from the "root" result relation. + */ +static List * +adjust_partition_colnos_using_map(List *colnos, AttrMap *attrMap) +{ + List *new_colnos = NIL; ListCell *lc; - Assert(map != NULL); /* else we shouldn't be here */ - attrMap = map->attrMap; + Assert(attrMap != NULL); /* else we shouldn't be here */ foreach(lc, colnos) { diff --git a/src/backend/executor/execReplication.c b/src/backend/executor/execReplication.c index 1a4fbdc38c..228e354701 100644 --- a/src/backend/executor/execReplication.c +++ b/src/backend/executor/execReplication.c @@ -486,7 +486,7 @@ ExecSimpleRelationUpdate(ResultRelInfo *resultRelInfo, resultRelInfo->ri_TrigDesc->trig_update_before_row) { if (!ExecBRUpdateTriggers(estate, epqstate, resultRelInfo, - tid, NULL, slot)) + tid, NULL, slot, NULL)) skip_tuple = true; /* "do nothing" */ } diff --git a/src/backend/executor/nodeModifyTable.c b/src/backend/executor/nodeModifyTable.c index 701fe05296..171575cd73 100644 --- a/src/backend/executor/nodeModifyTable.c +++ b/src/backend/executor/nodeModifyTable.c @@ -24,11 +24,20 @@ * values plus row-locating info for UPDATE and MERGE cases, or just the * row-locating info for DELETE cases. * + * MERGE runs a join between the source relation and the target + * table; if any WHEN NOT MATCHED clauses are present, then the + * join is an outer join. In this case, any unmatched tuples will + * have NULL row-locating info, and only INSERT can be run. But for + * matched tuples, then row-locating info is used to determine the + * tuple to UPDATE or DELETE. When all clauses are WHEN MATCHED, + * then an inner join is used, so all tuples contain row-locating info. + * * If the query specifies RETURNING, then the ModifyTable returns a * RETURNING tuple after completing each row insert, update, or delete. * It must be called again to continue the operation. Without RETURNING, * we just loop within the node until all the work is done, then - * return NULL. This avoids useless call/return overhead. + * return NULL. This avoids useless call/return overhead. (MERGE does + * not support RETURNING.) */ #include "postgres.h" @@ -78,6 +87,17 @@ typedef struct ModifyTableContext */ TupleTableSlot *planSlot; + /* + * During EvalPlanQual, project and return the new version of the new + * tuple + */ + TupleTableSlot *(*GetUpdateNewTuple) (ResultRelInfo *resultRelInfo, + TupleTableSlot *epqslot, + TupleTableSlot *oldSlot, + MergeActionState *relaction); + + /* MERGE specific */ + MergeActionState *relaction; /* MERGE action in progress */ /* * Information about the changes that were made concurrently to a tuple @@ -140,6 +160,28 @@ static TupleTableSlot *ExecPrepareTupleRouting(ModifyTableState *mtstate, ResultRelInfo *targetRelInfo, TupleTableSlot *slot, ResultRelInfo **partRelInfo); +static TupleTableSlot *internalGetUpdateNewTuple(ResultRelInfo *relinfo, + TupleTableSlot *planSlot, + TupleTableSlot *oldSlot, + MergeActionState *relaction); + +static TupleTableSlot *ExecMerge(ModifyTableContext *context, + ResultRelInfo *resultRelInfo, + ItemPointer tupleid, + bool canSetTag); +static void ExecInitMerge(ModifyTableState *mtstate, EState *estate); +static bool ExecMergeMatched(ModifyTableContext *context, + ResultRelInfo *resultRelInfo, + ItemPointer tupleid, + bool canSetTag); +static void ExecMergeNotMatched(ModifyTableContext *context, + ResultRelInfo *resultRelInfo, + bool canSetTag); +static TupleTableSlot *mergeGetUpdateNewTuple(ResultRelInfo *relinfo, + TupleTableSlot *planSlot, + TupleTableSlot *oldSlot, + MergeActionState *relaction); + /* * Verify that the tuples to be produced by INSERT match the @@ -616,21 +658,32 @@ ExecGetUpdateNewTuple(ResultRelInfo *relinfo, TupleTableSlot *planSlot, TupleTableSlot *oldSlot) { - ProjectionInfo *newProj = relinfo->ri_projectNew; - ExprContext *econtext; - /* Use a few extra Asserts to protect against outside callers */ Assert(relinfo->ri_projectNewInfoValid); Assert(planSlot != NULL && !TTS_EMPTY(planSlot)); Assert(oldSlot != NULL && !TTS_EMPTY(oldSlot)); + return internalGetUpdateNewTuple(relinfo, planSlot, oldSlot, NULL); +} + +/* + * Callback for ModifyTableState->GetUpdateNewTuple for use by regular UPDATE. + */ +static TupleTableSlot * +internalGetUpdateNewTuple(ResultRelInfo *relinfo, + TupleTableSlot *planSlot, + TupleTableSlot *oldSlot, + MergeActionState *relaction) +{ + ProjectionInfo *newProj = relinfo->ri_projectNew; + ExprContext *econtext; + econtext = newProj->pi_exprContext; econtext->ecxt_outertuple = planSlot; econtext->ecxt_scantuple = oldSlot; return ExecProject(newProj); } - /* ---------------------------------------------------------------- * ExecInsert * @@ -847,9 +900,17 @@ ExecInsert(ModifyTableContext *context, * partition, we should instead check UPDATE policies, because we are * executing policies defined on the target table, and not those * defined on the child partitions. + * + * If we're running MERGE, we refer to the action that we're executing + * to know if we're doing an INSERT or UPDATE to a partition table. */ - wco_kind = (mtstate->operation == CMD_UPDATE) ? - WCO_RLS_UPDATE_CHECK : WCO_RLS_INSERT_CHECK; + if (mtstate->operation == CMD_UPDATE) + wco_kind = WCO_RLS_UPDATE_CHECK; + else if (mtstate->operation == CMD_MERGE) + wco_kind = (context->relaction->mas_action->commandType == CMD_UPDATE) ? + WCO_RLS_UPDATE_CHECK : WCO_RLS_INSERT_CHECK; + else + wco_kind = WCO_RLS_INSERT_CHECK; /* * ExecWithCheckOptions() will skip any WCOs which are not of the kind @@ -1453,7 +1514,13 @@ ldelete:; ereport(ERROR, (errcode(ERRCODE_T_R_SERIALIZATION_FAILURE), errmsg("could not serialize access due to concurrent delete"))); - /* tuple already deleted; nothing to do */ + + /* + * tuple already deleted; nothing to do. But MERGE might want + * to handle it differently. We've already filled-in + * actionInfo with sufficient information for MERGE to look + * at. + */ return NULL; default: @@ -1659,7 +1726,8 @@ ExecCrossPartitionUpdate(ModifyTableContext *context, elog(ERROR, "failed to fetch tuple being updated"); /* and project the new tuple to retry the UPDATE with */ context->cpUpdateRetrySlot = - ExecGetUpdateNewTuple(resultRelInfo, epqslot, oldSlot); + context->GetUpdateNewTuple(resultRelInfo, epqslot, oldSlot, + context->relaction); return false; } } @@ -1718,7 +1786,8 @@ ExecUpdatePrologue(ModifyTableContext *context, ResultRelInfo *resultRelInfo, if (resultRelInfo->ri_TrigDesc && resultRelInfo->ri_TrigDesc->trig_update_before_row) return ExecBRUpdateTriggers(context->estate, context->epqstate, - resultRelInfo, tupleid, oldtuple, slot); + resultRelInfo, tupleid, oldtuple, slot, + &context->tmfd); return true; } @@ -1864,6 +1933,13 @@ lreplace:; return TM_Ok; } + /* + * No luck, a retry is needed. If running MERGE, we do not do so + * here; instead let it handle that on its own rules. + */ + if (context->relaction != NULL) + return TM_Updated; + /* * ExecCrossPartitionUpdate installed an updated version of the new * tuple in the retry slot; start over. @@ -2109,8 +2185,8 @@ redo_act: /* * If ExecUpdateAct reports that a cross-partition update was done, - * then the returning tuple has been projected and there's nothing - * else for us to do. + * then the RETURNING tuple (if any) has been projected and there's + * nothing else for us to do. */ if (updateCxt.crossPartUpdate) return context->cpUpdateReturningSlot; @@ -2337,9 +2413,9 @@ ExecOnConflictUpdate(ModifyTableContext *context, * to break. * * It is the user's responsibility to prevent this situation from - * occurring. These problems are why SQL-2003 similarly specifies - * that for SQL MERGE, an exception must be raised in the event of - * an attempt to update the same row twice. + * occurring. These problems are why the SQL standard similarly + * specifies that for SQL MERGE, an exception must be raised in + * the event of an attempt to update the same row twice. */ xminDatum = slot_getsysattr(existing, MinTransactionIdAttributeNumber, @@ -2350,7 +2426,9 @@ ExecOnConflictUpdate(ModifyTableContext *context, if (TransactionIdIsCurrentTransactionId(xmin)) ereport(ERROR, (errcode(ERRCODE_CARDINALITY_VIOLATION), - errmsg("ON CONFLICT DO UPDATE command cannot affect row a second time"), + /* translator: %s is a SQL command name */ + errmsg("%s command cannot affect row a second time", + "ON CONFLICT DO UPDATE"), errhint("Ensure that no rows proposed for insertion within the same command have duplicate constrained values."))); /* This shouldn't happen */ @@ -2490,6 +2568,705 @@ ExecOnConflictUpdate(ModifyTableContext *context, return true; } +/* + * Perform MERGE. + */ +static TupleTableSlot * +ExecMerge(ModifyTableContext *context, ResultRelInfo *resultRelInfo, + ItemPointer tupleid, bool canSetTag) +{ + bool matched; + + /*----- + * If we are dealing with a WHEN MATCHED case (tupleid is valid), we + * execute the first action for which the additional WHEN MATCHED AND + * quals pass. If an action without quals is found, that action is + * executed. + * + * Similarly, if we are dealing with WHEN NOT MATCHED case, we look at + * the given WHEN NOT MATCHED actions in sequence until one passes. + * + * Things get interesting in case of concurrent update/delete of the + * target tuple. Such concurrent update/delete is detected while we are + * executing a WHEN MATCHED action. + * + * A concurrent update can: + * + * 1. modify the target tuple so that it no longer satisfies the + * additional quals attached to the current WHEN MATCHED action + * + * In this case, we are still dealing with a WHEN MATCHED case. + * We recheck the list of WHEN MATCHED actions from the start and + * choose the first one that satisfies the new target tuple. + * + * 2. modify the target tuple so that the join quals no longer pass and + * hence the source tuple no longer has a match. + * + * In this case, the source tuple no longer matches the target tuple, + * so we now instead find a qualifying WHEN NOT MATCHED action to + * execute. + * + * XXX Hmmm, what if the updated tuple would now match one that was + * considered NOT MATCHED so far? + * + * A concurrent delete changes a WHEN MATCHED case to WHEN NOT MATCHED. + * + * ExecMergeMatched takes care of following the update chain and + * re-finding the qualifying WHEN MATCHED action, as long as the updated + * target tuple still satisfies the join quals, i.e., it remains a WHEN + * MATCHED case. If the tuple gets deleted or the join quals fail, it + * returns and we try ExecMergeNotMatched. Given that ExecMergeMatched + * always make progress by following the update chain and we never switch + * from ExecMergeNotMatched to ExecMergeMatched, there is no risk of a + * livelock. + */ + matched = tupleid != NULL; + if (matched) + matched = ExecMergeMatched(context, resultRelInfo, tupleid, canSetTag); + + /* + * Either we were dealing with a NOT MATCHED tuple or ExecMergeMatched() + * returned "false", indicating the previously MATCHED tuple no longer + * matches. + */ + if (!matched) + ExecMergeNotMatched(context, resultRelInfo, canSetTag); + + /* No RETURNING support yet */ + return NULL; +} + +/* + * Check and execute the first qualifying MATCHED action. The current target + * tuple is identified by tupleid. + * + * We start from the first WHEN MATCHED action and check if the WHEN quals + * pass, if any. If the WHEN quals for the first action do not pass, we + * check the second, then the third and so on. If we reach to the end, no + * action is taken and we return true, indicating that no further action is + * required for this tuple. + * + * If we do find a qualifying action, then we attempt to execute the action. + * + * If the tuple is concurrently updated, EvalPlanQual is run with the updated + * tuple to recheck the join quals. Note that the additional quals associated + * with individual actions are evaluated by this routine via ExecQual, while + * EvalPlanQual checks for the join quals. If EvalPlanQual tells us that the + * updated tuple still passes the join quals, then we restart from the first + * action to look for a qualifying action. Otherwise, we return false -- + * meaning that a NOT MATCHED action must now be executed for the current + * source tuple. + */ +static bool +ExecMergeMatched(ModifyTableContext *context, ResultRelInfo *resultRelInfo, + ItemPointer tupleid, bool canSetTag) +{ + ModifyTableState *mtstate = context->mtstate; + TupleTableSlot *newslot; + EState *estate = context->estate; + ExprContext *econtext = mtstate->ps.ps_ExprContext; + bool isNull; + EPQState *epqstate = &mtstate->mt_epqstate; + ListCell *l; + + /* + * If there are no WHEN MATCHED actions, we are done. + */ + if (resultRelInfo->ri_matchedMergeAction == NIL) + return true; + + /* + * Make tuple and any needed join variables available to ExecQual and + * ExecProject. The target's existing tuple is installed in the scantuple. + * Again, this target relation's slot is required only in the case of a + * MATCHED tuple and UPDATE/DELETE actions. + */ + econtext->ecxt_scantuple = resultRelInfo->ri_oldTupleSlot; + econtext->ecxt_innertuple = context->planSlot; + econtext->ecxt_outertuple = NULL; + +lmerge_matched:; + + /* + * This routine is only invoked for matched rows, and we must have found + * the tupleid of the target row in that case; fetch that tuple. + * + * We use SnapshotAny for this because we might get called again after + * EvalPlanQual returns us a new tuple, which may not be visible to our + * MVCC snapshot. + */ + + if (!table_tuple_fetch_row_version(resultRelInfo->ri_RelationDesc, + tupleid, + SnapshotAny, + resultRelInfo->ri_oldTupleSlot)) + elog(ERROR, "failed to fetch the target tuple"); + + foreach(l, resultRelInfo->ri_matchedMergeAction) + { + MergeActionState *relaction = (MergeActionState *) lfirst(l); + CmdType commandType = relaction->mas_action->commandType; + List *recheckIndexes = NIL; + TM_Result result; + UpdateContext updateCxt = {0}; + + /* + * Test condition, if any. + * + * In the absence of any condition, we perform the action + * unconditionally (no need to check separately since ExecQual() will + * return true if there are no conditions to evaluate). + */ + if (!ExecQual(relaction->mas_whenqual, econtext)) + continue; + + /* + * Check if the existing target tuple meets the USING checks of + * UPDATE/DELETE RLS policies. If those checks fail, we throw an + * error. + * + * The WITH CHECK quals are applied in ExecUpdate() and hence we need + * not do anything special to handle them. + * + * NOTE: We must do this after WHEN quals are evaluated, so that we + * check policies only when they matter. + */ + if (resultRelInfo->ri_WithCheckOptions) + { + ExecWithCheckOptions(commandType == CMD_UPDATE ? + WCO_RLS_MERGE_UPDATE_CHECK : WCO_RLS_MERGE_DELETE_CHECK, + resultRelInfo, + resultRelInfo->ri_oldTupleSlot, + context->mtstate->ps.state); + } + + /* Perform stated action */ + switch (commandType) + { + case CMD_UPDATE: + + /* + * Project the output tuple, and use that to update the table. + * We don't need to filter out junk attributes, because the + * UPDATE action's targetlist doesn't have any. + */ + newslot = ExecProject(relaction->mas_proj); + + context->relaction = relaction; + context->GetUpdateNewTuple = mergeGetUpdateNewTuple; + context->cpUpdateRetrySlot = NULL; + + if (!ExecUpdatePrologue(context, resultRelInfo, + tupleid, NULL, newslot)) + { + result = TM_Ok; + break; + } + ExecUpdatePrepareSlot(resultRelInfo, newslot, context->estate); + result = ExecUpdateAct(context, resultRelInfo, tupleid, NULL, + newslot, mtstate->canSetTag, &updateCxt); + if (result == TM_Ok && updateCxt.updated) + { + ExecUpdateEpilogue(context, &updateCxt, resultRelInfo, + tupleid, NULL, newslot, recheckIndexes); + mtstate->mt_merge_updated += 1; + } + + break; + + case CMD_DELETE: + context->relaction = relaction; + if (!ExecDeletePrologue(context, resultRelInfo, tupleid, + NULL, NULL)) + { + result = TM_Ok; + break; + } + result = ExecDeleteAct(context, resultRelInfo, tupleid, false); + if (result == TM_Ok) + { + ExecDeleteEpilogue(context, resultRelInfo, tupleid, NULL, + false); + mtstate->mt_merge_deleted += 1; + } + break; + + case CMD_NOTHING: + /* Doing nothing is always OK */ + result = TM_Ok; + break; + + default: + elog(ERROR, "unknown action in MERGE WHEN MATCHED clause"); + } + + switch (result) + { + case TM_Ok: + /* all good; perform final actions */ + if (canSetTag) + (estate->es_processed)++; + + break; + + case TM_SelfModified: + + /* + * The SQL standard disallows this for MERGE. + */ + if (TransactionIdIsCurrentTransactionId(context->tmfd.xmax)) + ereport(ERROR, + (errcode(ERRCODE_CARDINALITY_VIOLATION), + /* translator: %s is a SQL command name */ + errmsg("%s command cannot affect row a second time", + "MERGE"), + errhint("Ensure that not more than one source row matches any one target row."))); + /* This shouldn't happen */ + elog(ERROR, "attempted to update or delete invisible tuple"); + break; + + case TM_Deleted: + if (IsolationUsesXactSnapshot()) + ereport(ERROR, + (errcode(ERRCODE_T_R_SERIALIZATION_FAILURE), + errmsg("could not serialize access due to concurrent delete"))); + + /* + * If the tuple was already deleted, return to let caller + * handle it under NOT MATCHED clauses. + */ + return false; + + case TM_Updated: + { + Relation resultRelationDesc; + TupleTableSlot *epqslot, + *inputslot; + LockTupleMode lockmode; + + /* + * The target tuple was concurrently updated by some other + * transaction. + */ + + /* + * If cpUpdateRetrySlot is set, ExecCrossPartitionUpdate() + * must have detected that the tuple was concurrently + * updated, so we restart the search for an appropriate + * WHEN MATCHED clause to process the updated tuple. + * + * In this case, ExecDelete() would already have performed + * EvalPlanQual() on the latest version of the tuple, + * which in turn would already have been loaded into + * ri_oldTupleSlot, so no need to do either of those + * things. + * + * XXX why do we not check the WHEN NOT MATCHED list in + * this case? + */ + if (!TupIsNull(context->cpUpdateRetrySlot)) + goto lmerge_matched; + + /* + * Otherwise, we run the EvalPlanQual() with the new + * version of the tuple. If EvalPlanQual() does not return + * a tuple, then we switch to the NOT MATCHED list of + * actions. If it does return a tuple and the join qual is + * still satisfied, then we just need to recheck the + * MATCHED actions, starting from the top, and execute the + * first qualifying action. + */ + resultRelationDesc = resultRelInfo->ri_RelationDesc; + lockmode = ExecUpdateLockMode(estate, resultRelInfo); + + inputslot = EvalPlanQualSlot(epqstate, resultRelationDesc, + resultRelInfo->ri_RangeTableIndex); + + result = table_tuple_lock(resultRelationDesc, tupleid, + estate->es_snapshot, + inputslot, estate->es_output_cid, + lockmode, LockWaitBlock, + TUPLE_LOCK_FLAG_FIND_LAST_VERSION, + &context->tmfd); + switch (result) + { + case TM_Ok: + epqslot = EvalPlanQual(epqstate, + resultRelationDesc, + resultRelInfo->ri_RangeTableIndex, + inputslot); + + /* + * If we got no tuple, or the tuple we get has a + * NULL ctid, go back to caller: this one is not a + * MATCHED tuple anymore, so they can retry with + * NOT MATCHED actions. + */ + if (TupIsNull(epqslot)) + return false; + + (void) ExecGetJunkAttribute(epqslot, + resultRelInfo->ri_RowIdAttNo, + &isNull); + if (isNull) + return false; + + /* + * When a tuple was updated and migrated to + * another partition concurrently, the current + * MERGE implementation can't follow. There's + * probably a better way to handle this case, but + * it'd require recognizing the relation to which + * the tuple moved, and setting our current + * resultRelInfo to that. + */ + if (ItemPointerIndicatesMovedPartitions(&context->tmfd.ctid)) + ereport(ERROR, + (errcode(ERRCODE_T_R_SERIALIZATION_FAILURE), + errmsg("tuple to be deleted was already moved to another partition due to concurrent update"))); + + /* + * A non-NULL ctid means that we are still dealing + * with MATCHED case. Restart the loop so that we + * apply all the MATCHED rules again, to ensure + * that the first qualifying WHEN MATCHED action + * is executed. + * + * Update tupleid to that of the new tuple, for + * the refetch we do at the top. + */ + ItemPointerCopy(&context->tmfd.ctid, tupleid); + goto lmerge_matched; + + case TM_Deleted: + + /* + * tuple already deleted; tell caller to run NOT + * MATCHED actions + */ + return false; + + case TM_SelfModified: + + /* + * This can be reached when following an update + * chain from a tuple updated by another session, + * reaching a tuple that was already updated in + * this transaction. If previously modified by + * this command, ignore the redundant update, + * otherwise error out. + * + * See also response to TM_SelfModified in + * ExecUpdate(). + */ + if (context->tmfd.cmax != estate->es_output_cid) + ereport(ERROR, + (errcode(ERRCODE_TRIGGERED_DATA_CHANGE_VIOLATION), + errmsg("tuple to be updated or deleted was already modified by an operation triggered by the current command"), + errhint("Consider using an AFTER trigger instead of a BEFORE trigger to propagate changes to other rows."))); + return false; + + default: + /* see table_tuple_lock call in ExecDelete() */ + elog(ERROR, "unexpected table_tuple_lock status: %u", + result); + return false; + } + } + + case TM_Invisible: + case TM_WouldBlock: + case TM_BeingModified: + /* these should not occur */ + elog(ERROR, "unexpected tuple operation result: %d", result); + break; + } + + /* + * We've activated one of the WHEN clauses, so we don't search + * further. This is required behaviour, not an optimization. + */ + break; + } + + /* + * Successfully executed an action or no qualifying action was found. + */ + return true; +} + +/* + * Execute the first qualifying NOT MATCHED action. + */ +static void +ExecMergeNotMatched(ModifyTableContext *context, ResultRelInfo *resultRelInfo, + bool canSetTag) +{ + ModifyTableState *mtstate = context->mtstate; + ExprContext *econtext = mtstate->ps.ps_ExprContext; + List *actionStates = NIL; + ListCell *l; + + /* + * For INSERT actions, the root relation's merge action is OK since the + * INSERT's targetlist and the WHEN conditions can only refer to the + * source relation and hence it does not matter which result relation we + * work with. + * + * XXX does this mean that we can avoid creating copies of actionStates on + * partitioned tables, for not-matched actions? + */ + actionStates = resultRelInfo->ri_notMatchedMergeAction; + + /* + * Make source tuple available to ExecQual and ExecProject. We don't need + * the target tuple, since the WHEN quals and targetlist can't refer to + * the target columns. + */ + econtext->ecxt_scantuple = NULL; + econtext->ecxt_innertuple = context->planSlot; + econtext->ecxt_outertuple = NULL; + + foreach(l, actionStates) + { + MergeActionState *action = (MergeActionState *) lfirst(l); + CmdType commandType = action->mas_action->commandType; + TupleTableSlot *newslot; + + /* + * Test condition, if any. + * + * In the absence of any condition, we perform the action + * unconditionally (no need to check separately since ExecQual() will + * return true if there are no conditions to evaluate). + */ + if (!ExecQual(action->mas_whenqual, econtext)) + continue; + + /* Perform stated action */ + switch (commandType) + { + case CMD_INSERT: + + /* + * Project the tuple. In case of a partitioned table, the + * projection was already built to use the root's descriptor, + * so we don't need to map the tuple here. + */ + newslot = ExecProject(action->mas_proj); + context->relaction = action; + + (void) ExecInsert(context, mtstate->rootResultRelInfo, newslot, + canSetTag, NULL, NULL); + mtstate->mt_merge_inserted += 1; + break; + case CMD_NOTHING: + /* Do nothing */ + break; + default: + elog(ERROR, "unknown action in MERGE WHEN NOT MATCHED clause"); + } + + /* + * We've activated one of the WHEN clauses, so we don't search + * further. This is required behaviour, not an optimization. + */ + break; + } +} + +/* + * Initialize state for execution of MERGE. + */ +void +ExecInitMerge(ModifyTableState *mtstate, EState *estate) +{ + ModifyTable *node = (ModifyTable *) mtstate->ps.plan; + ResultRelInfo *rootRelInfo = mtstate->rootResultRelInfo; + ResultRelInfo *resultRelInfo; + ExprContext *econtext; + ListCell *lc; + int i; + + if (node->mergeActionLists == NIL) + return; + + mtstate->mt_merge_subcommands = 0; + + if (mtstate->ps.ps_ExprContext == NULL) + ExecAssignExprContext(estate, &mtstate->ps); + econtext = mtstate->ps.ps_ExprContext; + + /* + * Create a MergeActionState for each action on the mergeActionList and + * add it to either a list of matched actions or not-matched actions. + * + * Similar logic appears in ExecInitPartitionInfo(), so if changing + * anything here, do so there too. + */ + i = 0; + foreach(lc, node->mergeActionLists) + { + List *mergeActionList = lfirst(lc); + TupleDesc relationDesc; + ListCell *l; + + resultRelInfo = mtstate->resultRelInfo + i; + i++; + relationDesc = RelationGetDescr(resultRelInfo->ri_RelationDesc); + + /* initialize slots for MERGE fetches from this rel */ + if (unlikely(!resultRelInfo->ri_projectNewInfoValid)) + ExecInitMergeTupleSlots(mtstate, resultRelInfo); + + foreach(l, mergeActionList) + { + MergeAction *action = (MergeAction *) lfirst(l); + MergeActionState *action_state; + TupleTableSlot *tgtslot; + TupleDesc tgtdesc; + List **list; + + /* + * Build action merge state for this rel. (For partitions, + * equivalent code exists in ExecInitPartitionInfo.) + */ + action_state = makeNode(MergeActionState); + action_state->mas_action = action; + action_state->mas_whenqual = ExecInitQual((List *) action->qual, + &mtstate->ps); + + /* + * We create two lists - one for WHEN MATCHED actions and one for + * WHEN NOT MATCHED actions - and stick the MergeActionState into + * the appropriate list. + */ + if (action_state->mas_action->matched) + list = &resultRelInfo->ri_matchedMergeAction; + else + list = &resultRelInfo->ri_notMatchedMergeAction; + *list = lappend(*list, action_state); + + switch (action->commandType) + { + case CMD_INSERT: + ExecCheckPlanOutput(rootRelInfo->ri_RelationDesc, + action->targetList); + + /* + * If the MERGE targets a partitioned table, any INSERT + * actions must be routed through it, not the child + * relations. Initialize the routing struct and the root + * table's "new" tuple slot for that, if not already done. + * The projection we prepare, for all relations, uses the + * root relation descriptor, and targets the plan's root + * slot. (This is consistent with the fact that we + * checked the plan output to match the root relation, + * above.) + */ + if (rootRelInfo->ri_RelationDesc->rd_rel->relkind == + RELKIND_PARTITIONED_TABLE) + { + if (mtstate->mt_partition_tuple_routing == NULL) + { + /* + * Initialize planstate for routing if not already + * done. + * + * Note that the slot is managed as a standalone + * slot belonging to ModifyTableState, so we pass + * NULL for the 2nd argument. + */ + mtstate->mt_root_tuple_slot = + table_slot_create(rootRelInfo->ri_RelationDesc, + NULL); + mtstate->mt_partition_tuple_routing = + ExecSetupPartitionTupleRouting(estate, + rootRelInfo->ri_RelationDesc); + } + tgtslot = mtstate->mt_root_tuple_slot; + tgtdesc = RelationGetDescr(rootRelInfo->ri_RelationDesc); + } + else + { + /* not partitioned? use the stock relation and slot */ + tgtslot = resultRelInfo->ri_newTupleSlot; + tgtdesc = RelationGetDescr(resultRelInfo->ri_RelationDesc); + } + + action_state->mas_proj = + ExecBuildProjectionInfo(action->targetList, econtext, + tgtslot, + &mtstate->ps, + tgtdesc); + + mtstate->mt_merge_subcommands |= MERGE_INSERT; + break; + case CMD_UPDATE: + action_state->mas_proj = + ExecBuildUpdateProjection(action->targetList, + true, + action->updateColnos, + relationDesc, + econtext, + resultRelInfo->ri_newTupleSlot, + &mtstate->ps); + mtstate->mt_merge_subcommands |= MERGE_UPDATE; + break; + case CMD_DELETE: + mtstate->mt_merge_subcommands |= MERGE_DELETE; + break; + case CMD_NOTHING: + break; + default: + elog(ERROR, "unknown operation"); + break; + } + } + } +} + +/* + * Initializes the tuple slots in a ResultRelInfo for any MERGE action. + * + * We mark 'projectNewInfoValid' even though the projections themselves + * are not initialized here. + */ +void +ExecInitMergeTupleSlots(ModifyTableState *mtstate, + ResultRelInfo *resultRelInfo) +{ + EState *estate = mtstate->ps.state; + + Assert(!resultRelInfo->ri_projectNewInfoValid); + + resultRelInfo->ri_oldTupleSlot = + table_slot_create(resultRelInfo->ri_RelationDesc, + &estate->es_tupleTable); + resultRelInfo->ri_newTupleSlot = + table_slot_create(resultRelInfo->ri_RelationDesc, + &estate->es_tupleTable); + resultRelInfo->ri_projectNewInfoValid = true; +} + +/* + * Callback for ModifyTableContext->GetUpdateNewTuple for use by MERGE. It + * computes the updated tuple by projecting from the current merge action's + * projection. + */ +static TupleTableSlot * +mergeGetUpdateNewTuple(ResultRelInfo *relinfo, + TupleTableSlot *planSlot, + TupleTableSlot *oldSlot, + MergeActionState *relaction) +{ + ExprContext *econtext = relaction->mas_proj->pi_exprContext; + + econtext->ecxt_scantuple = oldSlot; + econtext->ecxt_innertuple = planSlot; + + return ExecProject(relaction->mas_proj); +} /* * Process BEFORE EACH STATEMENT triggers @@ -2514,6 +3291,14 @@ fireBSTriggers(ModifyTableState *node) case CMD_DELETE: ExecBSDeleteTriggers(node->ps.state, resultRelInfo); break; + case CMD_MERGE: + if (node->mt_merge_subcommands & MERGE_INSERT) + ExecBSInsertTriggers(node->ps.state, resultRelInfo); + if (node->mt_merge_subcommands & MERGE_UPDATE) + ExecBSUpdateTriggers(node->ps.state, resultRelInfo); + if (node->mt_merge_subcommands & MERGE_DELETE) + ExecBSDeleteTriggers(node->ps.state, resultRelInfo); + break; default: elog(ERROR, "unknown operation"); break; @@ -2547,6 +3332,17 @@ fireASTriggers(ModifyTableState *node) ExecASDeleteTriggers(node->ps.state, resultRelInfo, node->mt_transition_capture); break; + case CMD_MERGE: + if (node->mt_merge_subcommands & MERGE_DELETE) + ExecASDeleteTriggers(node->ps.state, resultRelInfo, + node->mt_transition_capture); + if (node->mt_merge_subcommands & MERGE_UPDATE) + ExecASUpdateTriggers(node->ps.state, resultRelInfo, + node->mt_transition_capture); + if (node->mt_merge_subcommands & MERGE_INSERT) + ExecASInsertTriggers(node->ps.state, resultRelInfo, + node->mt_transition_capture); + break; default: elog(ERROR, "unknown operation"); break; @@ -2749,7 +3545,28 @@ ExecModifyTable(PlanState *pstate) datum = ExecGetJunkAttribute(planSlot, node->mt_resultOidAttno, &isNull); if (isNull) + { + /* + * For commands other than MERGE, any tuples having InvalidOid + * for tableoid are errors. For MERGE, we may need to handle + * them as WHEN NOT MATCHED clauses if any, so do that. + * + * Note that we use the node's toplevel resultRelInfo, not any + * specific partition's. + */ + if (operation == CMD_MERGE) + { + EvalPlanQualSetSlot(&node->mt_epqstate, planSlot); + + context.planSlot = planSlot; + context.lockmode = 0; + + ExecMerge(&context, node->resultRelInfo, NULL, node->canSetTag); + continue; /* no RETURNING support yet */ + } + elog(ERROR, "tableoid is NULL"); + } resultoid = DatumGetObjectId(datum); /* If it's not the same as last time, we need to locate the rel */ @@ -2784,13 +3601,14 @@ ExecModifyTable(PlanState *pstate) oldtuple = NULL; /* - * For UPDATE/DELETE, fetch the row identity info for the tuple to be - * updated/deleted. For a heap relation, that's a TID; otherwise we - * may have a wholerow junk attr that carries the old tuple in toto. - * Keep this in step with the part of ExecInitModifyTable that sets up - * ri_RowIdAttNo. + * For UPDATE/DELETE/MERGE, fetch the row identity info for the tuple + * to be updated/deleted/merged. For a heap relation, that's a TID; + * otherwise we may have a wholerow junk attr that carries the old + * tuple in toto. Keep this in step with the part of + * ExecInitModifyTable that sets up ri_RowIdAttNo. */ - if (operation == CMD_UPDATE || operation == CMD_DELETE) + if (operation == CMD_UPDATE || operation == CMD_DELETE || + operation == CMD_MERGE) { char relkind; Datum datum; @@ -2806,9 +3624,30 @@ ExecModifyTable(PlanState *pstate) datum = ExecGetJunkAttribute(slot, resultRelInfo->ri_RowIdAttNo, &isNull); - /* shouldn't ever get a null result... */ + + /* + * For commands other than MERGE, any tuples having a null row + * identifier are errors. For MERGE, we may need to handle + * them as WHEN NOT MATCHED clauses if any, so do that. + * + * Note that we use the node's toplevel resultRelInfo, not any + * specific partition's. + */ if (isNull) + { + if (operation == CMD_MERGE) + { + EvalPlanQualSetSlot(&node->mt_epqstate, planSlot); + + context.planSlot = planSlot; + context.lockmode = 0; + + ExecMerge(&context, node->resultRelInfo, NULL, node->canSetTag); + continue; /* no RETURNING support yet */ + } + elog(ERROR, "ctid is NULL"); + } tupleid = (ItemPointer) DatumGetPointer(datum); tuple_ctid = *tupleid; /* be sure we don't free ctid!! */ @@ -2898,8 +3737,10 @@ ExecModifyTable(PlanState *pstate) oldSlot)) elog(ERROR, "failed to fetch tuple being updated"); } - slot = ExecGetUpdateNewTuple(resultRelInfo, planSlot, - oldSlot); + slot = internalGetUpdateNewTuple(resultRelInfo, planSlot, + oldSlot, NULL); + context.GetUpdateNewTuple = internalGetUpdateNewTuple; + context.relaction = NULL; /* Now apply the update. */ slot = ExecUpdate(&context, resultRelInfo, tupleid, oldtuple, @@ -2911,6 +3752,10 @@ ExecModifyTable(PlanState *pstate) true, false, node->canSetTag, NULL, NULL); break; + case CMD_MERGE: + slot = ExecMerge(&context, resultRelInfo, tupleid, node->canSetTag); + break; + default: elog(ERROR, "unknown operation"); break; @@ -3044,6 +3889,10 @@ ExecInitModifyTable(ModifyTable *node, EState *estate, int eflags) mtstate->resultRelInfo = (ResultRelInfo *) palloc(nrels * sizeof(ResultRelInfo)); + mtstate->mt_merge_inserted = 0; + mtstate->mt_merge_updated = 0; + mtstate->mt_merge_deleted = 0; + /*---------- * Resolve the target relation. This is the same as: * @@ -3147,12 +3996,13 @@ ExecInitModifyTable(ModifyTable *node, EState *estate, int eflags) } /* - * For UPDATE/DELETE, find the appropriate junk attr now, either a - * 'ctid' or 'wholerow' attribute depending on relkind. For foreign + * For UPDATE/DELETE/MERGE, find the appropriate junk attr now, either + * a 'ctid' or 'wholerow' attribute depending on relkind. For foreign * tables, the FDW might have created additional junk attr(s), but * those are no concern of ours. */ - if (operation == CMD_UPDATE || operation == CMD_DELETE) + if (operation == CMD_UPDATE || operation == CMD_DELETE || + operation == CMD_MERGE) { char relkind; @@ -3168,20 +4018,29 @@ ExecInitModifyTable(ModifyTable *node, EState *estate, int eflags) } else if (relkind == RELKIND_FOREIGN_TABLE) { + /* + * We don't support MERGE with foreign tables for now. (It's + * problematic because the implementation uses CTID.) + */ + Assert(operation != CMD_MERGE); + /* * When there is a row-level trigger, there should be a * wholerow attribute. We also require it to be present in - * UPDATE, so we can get the values of unchanged columns. + * UPDATE and MERGE, so we can get the values of unchanged + * columns. */ resultRelInfo->ri_RowIdAttNo = ExecFindJunkAttributeInTlist(subplan->targetlist, "wholerow"); - if (mtstate->operation == CMD_UPDATE && + if ((mtstate->operation == CMD_UPDATE || mtstate->operation == CMD_MERGE) && !AttributeNumberIsValid(resultRelInfo->ri_RowIdAttNo)) elog(ERROR, "could not find junk wholerow column"); } else { + /* No support for MERGE */ + Assert(operation != CMD_MERGE); /* Other valid target relkinds must provide wholerow */ resultRelInfo->ri_RowIdAttNo = ExecFindJunkAttributeInTlist(subplan->targetlist, @@ -3193,10 +4052,10 @@ ExecInitModifyTable(ModifyTable *node, EState *estate, int eflags) } /* - * If this is an inherited update/delete, there will be a junk attribute - * named "tableoid" present in the subplan's targetlist. It will be used - * to identify the result relation for a given tuple to be - * updated/deleted. + * If this is an inherited update/delete/merge, there will be a junk + * attribute named "tableoid" present in the subplan's targetlist. It + * will be used to identify the result relation for a given tuple to be + * updated/deleted/merged. */ mtstate->mt_resultOidAttno = ExecFindJunkAttributeInTlist(subplan->targetlist, "tableoid"); @@ -3209,8 +4068,9 @@ ExecInitModifyTable(ModifyTable *node, EState *estate, int eflags) /* * Build state for tuple routing if it's a partitioned INSERT. An UPDATE - * might need this too, but only if it actually moves tuples between - * partitions; in that case setup is done by ExecCrossPartitionUpdate. + * or MERGE might need this too, but only if it actually moves tuples + * between partitions; in that case setup is done by + * ExecCrossPartitionUpdate. */ if (rel->rd_rel->relkind == RELKIND_PARTITIONED_TABLE && operation == CMD_INSERT) @@ -3379,6 +4239,10 @@ ExecInitModifyTable(ModifyTable *node, EState *estate, int eflags) arowmarks = lappend(arowmarks, aerm); } + /* For a MERGE command, initialize its state */ + if (mtstate->operation == CMD_MERGE) + ExecInitMerge(mtstate, estate); + EvalPlanQualSetPlan(&mtstate->mt_epqstate, subplan, arowmarks); /* diff --git a/src/backend/executor/spi.c b/src/backend/executor/spi.c index a82e986667..042a5f8b0a 100644 --- a/src/backend/executor/spi.c +++ b/src/backend/executor/spi.c @@ -2881,6 +2881,9 @@ _SPI_pquery(QueryDesc *queryDesc, bool fire_triggers, uint64 tcount) else res = SPI_OK_UPDATE; break; + case CMD_MERGE: + res = SPI_OK_MERGE; + break; default: return SPI_ERROR_OPUNKNOWN; } diff --git a/src/backend/nodes/copyfuncs.c b/src/backend/nodes/copyfuncs.c index 2cbd8aa0df..c09172164b 100644 --- a/src/backend/nodes/copyfuncs.c +++ b/src/backend/nodes/copyfuncs.c @@ -228,6 +228,7 @@ _copyModifyTable(const ModifyTable *from) COPY_NODE_FIELD(onConflictWhere); COPY_SCALAR_FIELD(exclRelRTI); COPY_NODE_FIELD(exclRelTlist); + COPY_NODE_FIELD(mergeActionLists); return newnode; } @@ -2888,6 +2889,35 @@ _copyCommonTableExpr(const CommonTableExpr *from) return newnode; } +static MergeWhenClause * +_copyMergeWhenClause(const MergeWhenClause *from) +{ + MergeWhenClause *newnode = makeNode(MergeWhenClause); + + COPY_SCALAR_FIELD(matched); + COPY_SCALAR_FIELD(commandType); + COPY_SCALAR_FIELD(override); + COPY_NODE_FIELD(condition); + COPY_NODE_FIELD(targetList); + COPY_NODE_FIELD(values); + return newnode; +} + +static MergeAction * +_copyMergeAction(const MergeAction *from) +{ + MergeAction *newnode = makeNode(MergeAction); + + COPY_SCALAR_FIELD(matched); + COPY_SCALAR_FIELD(commandType); + COPY_SCALAR_FIELD(override); + COPY_NODE_FIELD(qual); + COPY_NODE_FIELD(targetList); + COPY_NODE_FIELD(updateColnos); + + return newnode; +} + static A_Expr * _copyA_Expr(const A_Expr *from) { @@ -3394,6 +3424,8 @@ _copyQuery(const Query *from) COPY_NODE_FIELD(setOperations); COPY_NODE_FIELD(constraintDeps); COPY_NODE_FIELD(withCheckOptions); + COPY_NODE_FIELD(mergeActionList); + COPY_SCALAR_FIELD(mergeUseOuterJoin); COPY_LOCATION_FIELD(stmt_location); COPY_SCALAR_FIELD(stmt_len); @@ -3457,6 +3489,20 @@ _copyUpdateStmt(const UpdateStmt *from) return newnode; } +static MergeStmt * +_copyMergeStmt(const MergeStmt *from) +{ + MergeStmt *newnode = makeNode(MergeStmt); + + COPY_NODE_FIELD(relation); + COPY_NODE_FIELD(sourceRelation); + COPY_NODE_FIELD(joinCondition); + COPY_NODE_FIELD(mergeWhenClauses); + COPY_NODE_FIELD(withClause); + + return newnode; +} + static SelectStmt * _copySelectStmt(const SelectStmt *from) { @@ -5662,6 +5708,9 @@ copyObjectImpl(const void *from) case T_UpdateStmt: retval = _copyUpdateStmt(from); break; + case T_MergeStmt: + retval = _copyMergeStmt(from); + break; case T_SelectStmt: retval = _copySelectStmt(from); break; @@ -6136,6 +6185,12 @@ copyObjectImpl(const void *from) case T_CommonTableExpr: retval = _copyCommonTableExpr(from); break; + case T_MergeWhenClause: + retval = _copyMergeWhenClause(from); + break; + case T_MergeAction: + retval = _copyMergeAction(from); + break; case T_ObjectWithArgs: retval = _copyObjectWithArgs(from); break; diff --git a/src/backend/nodes/equalfuncs.c b/src/backend/nodes/equalfuncs.c index 9f17e15e15..3fb423be47 100644 --- a/src/backend/nodes/equalfuncs.c +++ b/src/backend/nodes/equalfuncs.c @@ -1146,6 +1146,8 @@ _equalQuery(const Query *a, const Query *b) COMPARE_NODE_FIELD(setOperations); COMPARE_NODE_FIELD(constraintDeps); COMPARE_NODE_FIELD(withCheckOptions); + COMPARE_NODE_FIELD(mergeActionList); + COMPARE_SCALAR_FIELD(mergeUseOuterJoin); COMPARE_LOCATION_FIELD(stmt_location); COMPARE_SCALAR_FIELD(stmt_len); @@ -1201,6 +1203,18 @@ _equalUpdateStmt(const UpdateStmt *a, const UpdateStmt *b) return true; } +static bool +_equalMergeStmt(const MergeStmt *a, const MergeStmt *b) +{ + COMPARE_NODE_FIELD(relation); + COMPARE_NODE_FIELD(sourceRelation); + COMPARE_NODE_FIELD(joinCondition); + COMPARE_NODE_FIELD(mergeWhenClauses); + COMPARE_NODE_FIELD(withClause); + + return true; +} + static bool _equalSelectStmt(const SelectStmt *a, const SelectStmt *b) { @@ -3118,6 +3132,32 @@ _equalCommonTableExpr(const CommonTableExpr *a, const CommonTableExpr *b) return true; } +static bool +_equalMergeWhenClause(const MergeWhenClause *a, const MergeWhenClause *b) +{ + COMPARE_SCALAR_FIELD(matched); + COMPARE_SCALAR_FIELD(commandType); + COMPARE_SCALAR_FIELD(override); + COMPARE_NODE_FIELD(condition); + COMPARE_NODE_FIELD(targetList); + COMPARE_NODE_FIELD(values); + + return true; +} + +static bool +_equalMergeAction(const MergeAction *a, const MergeAction *b) +{ + COMPARE_SCALAR_FIELD(matched); + COMPARE_SCALAR_FIELD(commandType); + COMPARE_SCALAR_FIELD(override); + COMPARE_NODE_FIELD(qual); + COMPARE_NODE_FIELD(targetList); + COMPARE_NODE_FIELD(updateColnos); + + return true; +} + static bool _equalXmlSerialize(const XmlSerialize *a, const XmlSerialize *b) { @@ -3576,6 +3616,9 @@ equal(const void *a, const void *b) case T_UpdateStmt: retval = _equalUpdateStmt(a, b); break; + case T_MergeStmt: + retval = _equalMergeStmt(a, b); + break; case T_SelectStmt: retval = _equalSelectStmt(a, b); break; @@ -4050,6 +4093,12 @@ equal(const void *a, const void *b) case T_CommonTableExpr: retval = _equalCommonTableExpr(a, b); break; + case T_MergeWhenClause: + retval = _equalMergeWhenClause(a, b); + break; + case T_MergeAction: + retval = _equalMergeAction(a, b); + break; case T_ObjectWithArgs: retval = _equalObjectWithArgs(a, b); break; diff --git a/src/backend/nodes/nodeFuncs.c b/src/backend/nodes/nodeFuncs.c index 25cf282aab..50898246f9 100644 --- a/src/backend/nodes/nodeFuncs.c +++ b/src/backend/nodes/nodeFuncs.c @@ -2303,6 +2303,16 @@ expression_tree_walker(Node *node, return true; } break; + case T_MergeAction: + { + MergeAction *action = (MergeAction *) node; + + if (walker(action->targetList, context)) + return true; + if (walker(action->qual, context)) + return true; + } + break; case T_PartitionPruneStepOp: { PartitionPruneStepOp *opstep = (PartitionPruneStepOp *) node; @@ -2463,6 +2473,8 @@ query_tree_walker(Query *query, return true; if (walker((Node *) query->onConflict, context)) return true; + if (walker((Node *) query->mergeActionList, context)) + return true; if (walker((Node *) query->returningList, context)) return true; if (walker((Node *) query->jointree, context)) @@ -3252,6 +3264,18 @@ expression_tree_mutator(Node *node, return (Node *) newnode; } break; + case T_MergeAction: + { + MergeAction *action = (MergeAction *) node; + MergeAction *newnode; + + FLATCOPY(newnode, action, MergeAction); + MUTATE(newnode->qual, action->qual, Node *); + MUTATE(newnode->targetList, action->targetList, List *); + + return (Node *) newnode; + } + break; case T_PartitionPruneStepOp: { PartitionPruneStepOp *opstep = (PartitionPruneStepOp *) node; @@ -3464,6 +3488,7 @@ query_tree_mutator(Query *query, MUTATE(query->targetList, query->targetList, List *); MUTATE(query->withCheckOptions, query->withCheckOptions, List *); MUTATE(query->onConflict, query->onConflict, OnConflictExpr *); + MUTATE(query->mergeActionList, query->mergeActionList, List *); MUTATE(query->returningList, query->returningList, List *); MUTATE(query->jointree, query->jointree, FromExpr *); MUTATE(query->setOperations, query->setOperations, Node *); @@ -3656,9 +3681,9 @@ query_or_expression_tree_mutator(Node *node, * boundaries: we descend to everything that's possibly interesting. * * Currently, the node type coverage here extends only to DML statements - * (SELECT/INSERT/UPDATE/DELETE) and nodes that can appear in them, because - * this is used mainly during analysis of CTEs, and only DML statements can - * appear in CTEs. + * (SELECT/INSERT/UPDATE/DELETE/MERGE) and nodes that can appear in them, + * because this is used mainly during analysis of CTEs, and only DML + * statements can appear in CTEs. */ bool raw_expression_tree_walker(Node *node, @@ -3839,6 +3864,34 @@ raw_expression_tree_walker(Node *node, return true; } break; + case T_MergeStmt: + { + MergeStmt *stmt = (MergeStmt *) node; + + if (walker(stmt->relation, context)) + return true; + if (walker(stmt->sourceRelation, context)) + return true; + if (walker(stmt->joinCondition, context)) + return true; + if (walker(stmt->mergeWhenClauses, context)) + return true; + if (walker(stmt->withClause, context)) + return true; + } + break; + case T_MergeWhenClause: + { + MergeWhenClause *mergeWhenClause = (MergeWhenClause *) node; + + if (walker(mergeWhenClause->condition, context)) + return true; + if (walker(mergeWhenClause->targetList, context)) + return true; + if (walker(mergeWhenClause->values, context)) + return true; + } + break; case T_SelectStmt: { SelectStmt *stmt = (SelectStmt *) node; diff --git a/src/backend/nodes/outfuncs.c b/src/backend/nodes/outfuncs.c index c25f0bd684..0c01f35086 100644 --- a/src/backend/nodes/outfuncs.c +++ b/src/backend/nodes/outfuncs.c @@ -429,6 +429,7 @@ _outModifyTable(StringInfo str, const ModifyTable *node) WRITE_NODE_FIELD(onConflictWhere); WRITE_UINT_FIELD(exclRelRTI); WRITE_NODE_FIELD(exclRelTlist); + WRITE_NODE_FIELD(mergeActionLists); } static void @@ -2250,6 +2251,7 @@ _outModifyTablePath(StringInfo str, const ModifyTablePath *node) WRITE_NODE_FIELD(rowMarks); WRITE_NODE_FIELD(onconflict); WRITE_INT_FIELD(epqParam); + WRITE_NODE_FIELD(mergeActionLists); } static void @@ -3143,6 +3145,8 @@ _outQuery(StringInfo str, const Query *node) WRITE_NODE_FIELD(setOperations); WRITE_NODE_FIELD(constraintDeps); WRITE_NODE_FIELD(withCheckOptions); + WRITE_NODE_FIELD(mergeActionList); + WRITE_BOOL_FIELD(mergeUseOuterJoin); WRITE_LOCATION_FIELD(stmt_location); WRITE_INT_FIELD(stmt_len); } @@ -3271,6 +3275,32 @@ _outCommonTableExpr(StringInfo str, const CommonTableExpr *node) WRITE_NODE_FIELD(ctecolcollations); } +static void +_outMergeWhenClause(StringInfo str, const MergeWhenClause *node) +{ + WRITE_NODE_TYPE("MERGEWHENCLAUSE"); + + WRITE_BOOL_FIELD(matched); + WRITE_ENUM_FIELD(commandType, CmdType); + WRITE_ENUM_FIELD(override, OverridingKind); + WRITE_NODE_FIELD(condition); + WRITE_NODE_FIELD(targetList); + WRITE_NODE_FIELD(values); +} + +static void +_outMergeAction(StringInfo str, const MergeAction *node) +{ + WRITE_NODE_TYPE("MERGEACTION"); + + WRITE_BOOL_FIELD(matched); + WRITE_ENUM_FIELD(commandType, CmdType); + WRITE_ENUM_FIELD(override, OverridingKind); + WRITE_NODE_FIELD(qual); + WRITE_NODE_FIELD(targetList); + WRITE_NODE_FIELD(updateColnos); +} + static void _outSetOperationStmt(StringInfo str, const SetOperationStmt *node) { @@ -4480,6 +4510,12 @@ outNode(StringInfo str, const void *obj) case T_CommonTableExpr: _outCommonTableExpr(str, obj); break; + case T_MergeWhenClause: + _outMergeWhenClause(str, obj); + break; + case T_MergeAction: + _outMergeAction(str, obj); + break; case T_SetOperationStmt: _outSetOperationStmt(str, obj); break; diff --git a/src/backend/nodes/readfuncs.c b/src/backend/nodes/readfuncs.c index e0b3ad1ed2..3ee8ba6f15 100644 --- a/src/backend/nodes/readfuncs.c +++ b/src/backend/nodes/readfuncs.c @@ -283,6 +283,8 @@ _readQuery(void) READ_NODE_FIELD(setOperations); READ_NODE_FIELD(constraintDeps); READ_NODE_FIELD(withCheckOptions); + READ_NODE_FIELD(mergeActionList); + READ_BOOL_FIELD(mergeUseOuterJoin); READ_LOCATION_FIELD(stmt_location); READ_INT_FIELD(stmt_len); @@ -472,6 +474,42 @@ _readCommonTableExpr(void) READ_DONE(); } +/* + * _readMergeWhenClause + */ +static MergeWhenClause * +_readMergeWhenClause(void) +{ + READ_LOCALS(MergeWhenClause); + + READ_BOOL_FIELD(matched); + READ_ENUM_FIELD(commandType, CmdType); + READ_NODE_FIELD(condition); + READ_NODE_FIELD(targetList); + READ_NODE_FIELD(values); + READ_ENUM_FIELD(override, OverridingKind); + + READ_DONE(); +} + +/* + * _readMergeAction + */ +static MergeAction * +_readMergeAction(void) +{ + READ_LOCALS(MergeAction); + + READ_BOOL_FIELD(matched); + READ_ENUM_FIELD(commandType, CmdType); + READ_ENUM_FIELD(override, OverridingKind); + READ_NODE_FIELD(qual); + READ_NODE_FIELD(targetList); + READ_NODE_FIELD(updateColnos); + + READ_DONE(); +} + /* * _readSetOperationStmt */ @@ -1765,6 +1803,7 @@ _readModifyTable(void) READ_NODE_FIELD(onConflictWhere); READ_UINT_FIELD(exclRelRTI); READ_NODE_FIELD(exclRelTlist); + READ_NODE_FIELD(mergeActionLists); READ_DONE(); } @@ -2809,6 +2848,10 @@ parseNodeString(void) return_value = _readCTECycleClause(); else if (MATCH("COMMONTABLEEXPR", 15)) return_value = _readCommonTableExpr(); + else if (MATCH("MERGEWHENCLAUSE", 15)) + return_value = _readMergeWhenClause(); + else if (MATCH("MERGEACTION", 11)) + return_value = _readMergeAction(); else if (MATCH("SETOPERATIONSTMT", 16)) return_value = _readSetOperationStmt(); else if (MATCH("ALIAS", 5)) diff --git a/src/backend/optimizer/plan/createplan.c b/src/backend/optimizer/plan/createplan.c index fa069a217c..179c87c671 100644 --- a/src/backend/optimizer/plan/createplan.c +++ b/src/backend/optimizer/plan/createplan.c @@ -310,7 +310,8 @@ static ModifyTable *make_modifytable(PlannerInfo *root, Plan *subplan, List *resultRelations, List *updateColnosLists, List *withCheckOptionLists, List *returningLists, - List *rowMarks, OnConflictExpr *onconflict, int epqParam); + List *rowMarks, OnConflictExpr *onconflict, + List *mergeActionList, int epqParam); static GatherMerge *create_gather_merge_plan(PlannerInfo *root, GatherMergePath *best_path); @@ -2775,6 +2776,7 @@ create_modifytable_plan(PlannerInfo *root, ModifyTablePath *best_path) best_path->returningLists, best_path->rowMarks, best_path->onconflict, + best_path->mergeActionLists, best_path->epqParam); copy_generic_path_info(&plan->plan, &best_path->path); @@ -6924,7 +6926,8 @@ make_modifytable(PlannerInfo *root, Plan *subplan, List *resultRelations, List *updateColnosLists, List *withCheckOptionLists, List *returningLists, - List *rowMarks, OnConflictExpr *onconflict, int epqParam) + List *rowMarks, OnConflictExpr *onconflict, + List *mergeActionLists, int epqParam) { ModifyTable *node = makeNode(ModifyTable); List *fdw_private_list; @@ -6932,9 +6935,10 @@ make_modifytable(PlannerInfo *root, Plan *subplan, ListCell *lc; int i; - Assert(operation == CMD_UPDATE ? - list_length(resultRelations) == list_length(updateColnosLists) : - updateColnosLists == NIL); + Assert(operation == CMD_MERGE || + (operation == CMD_UPDATE ? + list_length(resultRelations) == list_length(updateColnosLists) : + updateColnosLists == NIL)); Assert(withCheckOptionLists == NIL || list_length(resultRelations) == list_length(withCheckOptionLists)); Assert(returningLists == NIL || @@ -6992,6 +6996,7 @@ make_modifytable(PlannerInfo *root, Plan *subplan, node->withCheckOptionLists = withCheckOptionLists; node->returningLists = returningLists; node->rowMarks = rowMarks; + node->mergeActionLists = mergeActionLists; node->epqParam = epqParam; /* diff --git a/src/backend/optimizer/plan/planner.c b/src/backend/optimizer/plan/planner.c index bd09f85aea..547fda20a2 100644 --- a/src/backend/optimizer/plan/planner.c +++ b/src/backend/optimizer/plan/planner.c @@ -649,6 +649,11 @@ subquery_planner(PlannerGlobal *glob, Query *parse, if (parse->cteList) SS_process_ctes(root); + /* + * If it's a MERGE command, transform the joinlist as appropriate. + */ + transform_MERGE_to_join(parse); + /* * If the FROM clause is empty, replace it with a dummy RTE_RESULT RTE, so * that we don't need so many special cases to deal with that situation. @@ -849,6 +854,20 @@ subquery_planner(PlannerGlobal *glob, Query *parse, /* exclRelTlist contains only Vars, so no preprocessing needed */ } + foreach(l, parse->mergeActionList) + { + MergeAction *action = (MergeAction *) lfirst(l); + + action->targetList = (List *) + preprocess_expression(root, + (Node *) action->targetList, + EXPRKIND_TARGET); + action->qual = + preprocess_expression(root, + (Node *) action->qual, + EXPRKIND_QUAL); + } + root->append_rel_list = (List *) preprocess_expression(root, (Node *) root->append_rel_list, EXPRKIND_APPINFO); @@ -1714,7 +1733,7 @@ grouping_planner(PlannerInfo *root, double tuple_fraction) } /* - * If this is an INSERT/UPDATE/DELETE, add the ModifyTable node. + * If this is an INSERT/UPDATE/DELETE/MERGE, add the ModifyTable node. */ if (parse->commandType != CMD_SELECT) { @@ -1723,6 +1742,7 @@ grouping_planner(PlannerInfo *root, double tuple_fraction) List *updateColnosLists = NIL; List *withCheckOptionLists = NIL; List *returningLists = NIL; + List *mergeActionLists = NIL; List *rowMarks; if (bms_membership(root->all_result_relids) == BMS_MULTIPLE) @@ -1789,6 +1809,43 @@ grouping_planner(PlannerInfo *root, double tuple_fraction) returningLists = lappend(returningLists, returningList); } + if (parse->mergeActionList) + { + ListCell *l; + List *mergeActionList = NIL; + + /* + * Copy MergeActions and translate stuff that + * references attribute numbers. + */ + foreach(l, parse->mergeActionList) + { + MergeAction *action = lfirst(l), + *leaf_action = copyObject(action); + + leaf_action->qual = + adjust_appendrel_attrs_multilevel(root, + (Node *) action->qual, + this_result_rel->relids, + top_result_rel->relids); + leaf_action->targetList = (List *) + adjust_appendrel_attrs_multilevel(root, + (Node *) action->targetList, + this_result_rel->relids, + top_result_rel->relids); + if (leaf_action->commandType == CMD_UPDATE) + leaf_action->updateColnos = + adjust_inherited_attnums_multilevel(root, + action->updateColnos, + this_result_rel->relid, + top_result_rel->relid); + mergeActionList = lappend(mergeActionList, + leaf_action); + } + + mergeActionLists = lappend(mergeActionLists, + mergeActionList); + } } if (resultRelations == NIL) @@ -1811,6 +1868,8 @@ grouping_planner(PlannerInfo *root, double tuple_fraction) withCheckOptionLists = list_make1(parse->withCheckOptions); if (parse->returningList) returningLists = list_make1(parse->returningList); + if (parse->mergeActionList) + mergeActionLists = list_make1(parse->mergeActionList); } } else @@ -1823,6 +1882,8 @@ grouping_planner(PlannerInfo *root, double tuple_fraction) withCheckOptionLists = list_make1(parse->withCheckOptions); if (parse->returningList) returningLists = list_make1(parse->returningList); + if (parse->mergeActionList) + mergeActionLists = list_make1(parse->mergeActionList); } /* @@ -1859,6 +1920,7 @@ grouping_planner(PlannerInfo *root, double tuple_fraction) returningLists, rowMarks, parse->onConflict, + mergeActionLists, assign_special_exec_param(root)); } diff --git a/src/backend/optimizer/plan/setrefs.c b/src/backend/optimizer/plan/setrefs.c index a7b11b7f03..bf4c722c02 100644 --- a/src/backend/optimizer/plan/setrefs.c +++ b/src/backend/optimizer/plan/setrefs.c @@ -952,6 +952,7 @@ set_plan_refs(PlannerInfo *root, Plan *plan, int rtoffset) case T_ModifyTable: { ModifyTable *splan = (ModifyTable *) plan; + Plan *subplan = outerPlan(splan); Assert(splan->plan.targetlist == NIL); Assert(splan->plan.qual == NIL); @@ -963,7 +964,6 @@ set_plan_refs(PlannerInfo *root, Plan *plan, int rtoffset) if (splan->returningLists) { List *newRL = NIL; - Plan *subplan = outerPlan(splan); ListCell *lcrl, *lcrr; @@ -1030,6 +1030,68 @@ set_plan_refs(PlannerInfo *root, Plan *plan, int rtoffset) fix_scan_list(root, splan->exclRelTlist, rtoffset, 1); } + /* + * The MERGE statement produces the target rows by performing + * a right join between the target relation and the source + * relation (which could be a plain relation or a subquery). + * The INSERT and UPDATE actions of the MERGE statement + * require access to the columns from the source relation. We + * arrange things so that the source relation attributes are + * available as INNER_VAR and the target relation attributes + * are available from the scan tuple. + */ + if (splan->mergeActionLists != NIL) + { + ListCell *lca, + *lcr; + + /* + * Fix the targetList of individual action nodes so that + * the so-called "source relation" Vars are referenced as + * INNER_VAR. Note that for this to work correctly during + * execution, the ecxt_innertuple must be set to the tuple + * obtained by executing the subplan, which is what + * constitutes the "source relation". + * + * We leave the Vars from the result relation (i.e. the + * target relation) unchanged i.e. those Vars would be + * picked from the scan slot. So during execution, we must + * ensure that ecxt_scantuple is setup correctly to refer + * to the tuple from the target relation. + */ + indexed_tlist *itlist; + + itlist = build_tlist_index(subplan->targetlist); + + forboth(lca, splan->mergeActionLists, + lcr, splan->resultRelations) + { + List *mergeActionList = lfirst(lca); + Index resultrel = lfirst_int(lcr); + + foreach(l, mergeActionList) + { + MergeAction *action = (MergeAction *) lfirst(l); + + /* Fix targetList of each action. */ + action->targetList = fix_join_expr(root, + action->targetList, + NULL, itlist, + resultrel, + rtoffset, + NUM_EXEC_TLIST(plan)); + + /* Fix quals too. */ + action->qual = (Node *) fix_join_expr(root, + (List *) action->qual, + NULL, itlist, + resultrel, + rtoffset, + NUM_EXEC_QUAL(plan)); + } + } + } + splan->nominalRelation += rtoffset; if (splan->rootRelation) splan->rootRelation += rtoffset; diff --git a/src/backend/optimizer/prep/prepjointree.c b/src/backend/optimizer/prep/prepjointree.c index 74823e8437..0bd99acf83 100644 --- a/src/backend/optimizer/prep/prepjointree.c +++ b/src/backend/optimizer/prep/prepjointree.c @@ -132,6 +132,86 @@ static void fix_append_rel_relids(List *append_rel_list, int varno, static Node *find_jointree_node_for_rel(Node *jtnode, int relid); +/* + * transform_MERGE_to_join + * Replace a MERGE's jointree to also include the target relation. + */ +void +transform_MERGE_to_join(Query *parse) +{ + RangeTblEntry *joinrte; + JoinExpr *joinexpr; + JoinType jointype; + int joinrti; + List *vars; + + if (parse->commandType != CMD_MERGE) + return; + + /* XXX probably bogus */ + vars = NIL; + + /* + * When any WHEN NOT MATCHED THEN INSERT clauses exist, we need to use an + * outer join so that we process all unmatched tuples from the source + * relation. If none exist, we can use an inner join. + */ + if (parse->mergeUseOuterJoin) + jointype = JOIN_RIGHT; + else + jointype = JOIN_INNER; + + /* Manufacture a join RTE to use. */ + joinrte = makeNode(RangeTblEntry); + joinrte->rtekind = RTE_JOIN; + joinrte->jointype = jointype; + joinrte->joinmergedcols = 0; + joinrte->joinaliasvars = vars; + joinrte->joinleftcols = NIL; /* MERGE does not allow JOIN USING */ + joinrte->joinrightcols = NIL; /* ditto */ + joinrte->join_using_alias = NULL; + + joinrte->alias = NULL; + joinrte->eref = makeAlias("*MERGE*", NIL); + joinrte->lateral = false; + joinrte->inh = false; + joinrte->inFromCl = true; + joinrte->requiredPerms = 0; + joinrte->checkAsUser = InvalidOid; + joinrte->selectedCols = NULL; + joinrte->insertedCols = NULL; + joinrte->updatedCols = NULL; + joinrte->extraUpdatedCols = NULL; + joinrte->securityQuals = NIL; + + /* + * Add completed RTE to pstate's range table list, so that we know its + * index. + */ + parse->rtable = lappend(parse->rtable, joinrte); + joinrti = list_length(parse->rtable); + + /* + * Create a JOIN between the target and the source relation. + */ + joinexpr = makeNode(JoinExpr); + joinexpr->jointype = jointype; + joinexpr->isNatural = false; + joinexpr->larg = (Node *) makeNode(RangeTblRef); + ((RangeTblRef *) joinexpr->larg)->rtindex = parse->resultRelation; + joinexpr->rarg = linitial(parse->jointree->fromlist); /* original join */ + joinexpr->usingClause = NIL; + joinexpr->join_using_alias = NULL; + /* The quals are removed from the jointree and into this specific join */ + joinexpr->quals = parse->jointree->quals; + joinexpr->alias = NULL; + joinexpr->rtindex = joinrti; + + /* Make the new join be the sole entry in the query's jointree */ + parse->jointree->fromlist = list_make1(joinexpr); + parse->jointree->quals = NULL; +} + /* * replace_empty_jointree * If the Query's jointree is empty, replace it with a dummy RTE_RESULT @@ -2058,6 +2138,17 @@ perform_pullup_replace_vars(PlannerInfo *root, * can't contain any references to a subquery. */ } + if (parse->mergeActionList) + { + foreach(lc, parse->mergeActionList) + { + MergeAction *action = lfirst(lc); + + action->qual = pullup_replace_vars(action->qual, rvcontext); + action->targetList = (List *) + pullup_replace_vars((Node *) action->targetList, rvcontext); + } + } replace_vars_in_jointree((Node *) parse->jointree, rvcontext, lowest_nulling_outer_join); Assert(parse->setOperations == NULL); diff --git a/src/backend/optimizer/prep/preptlist.c b/src/backend/optimizer/prep/preptlist.c index 95e82cf958..99ab3d7559 100644 --- a/src/backend/optimizer/prep/preptlist.c +++ b/src/backend/optimizer/prep/preptlist.c @@ -124,6 +124,43 @@ preprocess_targetlist(PlannerInfo *root) tlist = root->processed_tlist; } + /* + * For MERGE we need to handle the target list for the target relation, + * and also target list for each action (only INSERT/UPDATE matter). + */ + if (command_type == CMD_MERGE) + { + ListCell *l; + + /* + * For MERGE, add any junk column(s) needed to allow the executor to + * identify the rows to be inserted or updated. + */ + root->processed_tlist = tlist; + add_row_identity_columns(root, result_relation, + target_rte, target_relation); + + tlist = root->processed_tlist; + + /* + * For MERGE, handle targetlist of each MergeAction separately. Give + * the same treatment to MergeAction->targetList as we would have + * given to a regular INSERT. For UPDATE, collect the column numbers + * being modified. + */ + foreach(l, parse->mergeActionList) + { + MergeAction *action = (MergeAction *) lfirst(l); + + if (action->commandType == CMD_INSERT) + action->targetList = expand_insert_targetlist(action->targetList, + target_relation); + else if (action->commandType == CMD_UPDATE) + action->updateColnos = + extract_update_targetlist_colnos(action->targetList); + } + } + /* * Add necessary junk columns for rowmarked rels. These values are needed * for locking of rels selected FOR UPDATE/SHARE, and to do EvalPlanQual diff --git a/src/backend/optimizer/util/appendinfo.c b/src/backend/optimizer/util/appendinfo.c index 2f06fa743c..9d4bb47027 100644 --- a/src/backend/optimizer/util/appendinfo.c +++ b/src/backend/optimizer/util/appendinfo.c @@ -774,8 +774,8 @@ add_row_identity_var(PlannerInfo *root, Var *orig_var, Assert(orig_var->varlevelsup == 0); /* - * If we're doing non-inherited UPDATE/DELETE, there's little need for - * ROWID_VAR shenanigans. Just shove the presented Var into the + * If we're doing non-inherited UPDATE/DELETE/MERGE, there's little need + * for ROWID_VAR shenanigans. Just shove the presented Var into the * processed_tlist, and we're done. */ if (rtindex == root->parse->resultRelation) @@ -862,14 +862,16 @@ add_row_identity_columns(PlannerInfo *root, Index rtindex, char relkind = target_relation->rd_rel->relkind; Var *var; - Assert(commandType == CMD_UPDATE || commandType == CMD_DELETE); + Assert(commandType == CMD_UPDATE || commandType == CMD_DELETE || commandType == CMD_MERGE); - if (relkind == RELKIND_RELATION || + if (commandType == CMD_MERGE || + relkind == RELKIND_RELATION || relkind == RELKIND_MATVIEW || relkind == RELKIND_PARTITIONED_TABLE) { /* - * Emit CTID so that executor can find the row to update or delete. + * Emit CTID so that executor can find the row to merge, update or + * delete. */ var = makeVar(rtindex, SelfItemPointerAttributeNumber, @@ -942,8 +944,11 @@ distribute_row_identity_vars(PlannerInfo *root) RelOptInfo *target_rel; ListCell *lc; - /* There's nothing to do if this isn't an inherited UPDATE/DELETE. */ - if (parse->commandType != CMD_UPDATE && parse->commandType != CMD_DELETE) + /* + * There's nothing to do if this isn't an inherited UPDATE/DELETE/MERGE. + */ + if (parse->commandType != CMD_UPDATE && parse->commandType != CMD_DELETE && + parse->commandType != CMD_MERGE) { Assert(root->row_identity_vars == NIL); return; diff --git a/src/backend/optimizer/util/pathnode.c b/src/backend/optimizer/util/pathnode.c index 5c32c96b71..99df76b6b7 100644 --- a/src/backend/optimizer/util/pathnode.c +++ b/src/backend/optimizer/util/pathnode.c @@ -3620,6 +3620,7 @@ create_lockrows_path(PlannerInfo *root, RelOptInfo *rel, * 'rowMarks' is a list of PlanRowMarks (non-locking only) * 'onconflict' is the ON CONFLICT clause, or NULL * 'epqParam' is the ID of Param for EvalPlanQual re-eval + * 'mergeActionLists' is a list of lists of MERGE actions (one per rel) */ ModifyTablePath * create_modifytable_path(PlannerInfo *root, RelOptInfo *rel, @@ -3631,13 +3632,14 @@ create_modifytable_path(PlannerInfo *root, RelOptInfo *rel, List *updateColnosLists, List *withCheckOptionLists, List *returningLists, List *rowMarks, OnConflictExpr *onconflict, - int epqParam) + List *mergeActionLists, int epqParam) { ModifyTablePath *pathnode = makeNode(ModifyTablePath); - Assert(operation == CMD_UPDATE ? - list_length(resultRelations) == list_length(updateColnosLists) : - updateColnosLists == NIL); + Assert(operation == CMD_MERGE || + (operation == CMD_UPDATE ? + list_length(resultRelations) == list_length(updateColnosLists) : + updateColnosLists == NIL)); Assert(withCheckOptionLists == NIL || list_length(resultRelations) == list_length(withCheckOptionLists)); Assert(returningLists == NIL || @@ -3697,6 +3699,7 @@ create_modifytable_path(PlannerInfo *root, RelOptInfo *rel, pathnode->rowMarks = rowMarks; pathnode->onconflict = onconflict; pathnode->epqParam = epqParam; + pathnode->mergeActionLists = mergeActionLists; return pathnode; } diff --git a/src/backend/optimizer/util/plancat.c b/src/backend/optimizer/util/plancat.c index a5002ad895..df97b79917 100644 --- a/src/backend/optimizer/util/plancat.c +++ b/src/backend/optimizer/util/plancat.c @@ -2167,6 +2167,10 @@ has_row_triggers(PlannerInfo *root, Index rti, CmdType event) trigDesc->trig_delete_before_row)) result = true; break; + /* There is no separate event for MERGE, only INSERT/UPDATE/DELETE */ + case CMD_MERGE: + result = false; + break; default: elog(ERROR, "unrecognized CmdType: %d", (int) event); break; diff --git a/src/backend/parser/Makefile b/src/backend/parser/Makefile index 5ddb9a92f0..9f1c4022bb 100644 --- a/src/backend/parser/Makefile +++ b/src/backend/parser/Makefile @@ -23,6 +23,7 @@ OBJS = \ parse_enr.o \ parse_expr.o \ parse_func.o \ + parse_merge.o \ parse_node.o \ parse_oper.o \ parse_param.o \ diff --git a/src/backend/parser/analyze.c b/src/backend/parser/analyze.c index 61026753a3..0144284aa3 100644 --- a/src/backend/parser/analyze.c +++ b/src/backend/parser/analyze.c @@ -39,6 +39,7 @@ #include "parser/parse_cte.h" #include "parser/parse_expr.h" #include "parser/parse_func.h" +#include "parser/parse_merge.h" #include "parser/parse_oper.h" #include "parser/parse_param.h" #include "parser/parse_relation.h" @@ -60,9 +61,6 @@ post_parse_analyze_hook_type post_parse_analyze_hook = NULL; static Query *transformOptionalSelectInto(ParseState *pstate, Node *parseTree); static Query *transformDeleteStmt(ParseState *pstate, DeleteStmt *stmt); static Query *transformInsertStmt(ParseState *pstate, InsertStmt *stmt); -static List *transformInsertRow(ParseState *pstate, List *exprlist, - List *stmtcols, List *icolumns, List *attrnos, - bool strip_indirection); static OnConflictExpr *transformOnConflictClause(ParseState *pstate, OnConflictClause *onConflictClause); static int count_rowexpr_columns(ParseState *pstate, Node *expr); @@ -76,8 +74,6 @@ static void determineRecursiveColTypes(ParseState *pstate, static Query *transformReturnStmt(ParseState *pstate, ReturnStmt *stmt); static Query *transformUpdateStmt(ParseState *pstate, UpdateStmt *stmt); static List *transformReturningList(ParseState *pstate, List *returningList); -static List *transformUpdateTargetList(ParseState *pstate, - List *targetList); static Query *transformPLAssignStmt(ParseState *pstate, PLAssignStmt *stmt); static Query *transformDeclareCursorStmt(ParseState *pstate, @@ -330,6 +326,7 @@ transformStmt(ParseState *pstate, Node *parseTree) case T_InsertStmt: case T_UpdateStmt: case T_DeleteStmt: + case T_MergeStmt: (void) test_raw_expression_coverage(parseTree, NULL); break; default: @@ -354,6 +351,10 @@ transformStmt(ParseState *pstate, Node *parseTree) result = transformUpdateStmt(pstate, (UpdateStmt *) parseTree); break; + case T_MergeStmt: + result = transformMergeStmt(pstate, (MergeStmt *) parseTree); + break; + case T_SelectStmt: { SelectStmt *n = (SelectStmt *) parseTree; @@ -438,6 +439,7 @@ analyze_requires_snapshot(RawStmt *parseTree) case T_InsertStmt: case T_DeleteStmt: case T_UpdateStmt: + case T_MergeStmt: case T_SelectStmt: case T_PLAssignStmt: result = true; @@ -956,7 +958,7 @@ transformInsertStmt(ParseState *pstate, InsertStmt *stmt) * attrnos: integer column numbers (must be same length as icolumns) * strip_indirection: if true, remove any field/array assignment nodes */ -static List * +List * transformInsertRow(ParseState *pstate, List *exprlist, List *stmtcols, List *icolumns, List *attrnos, bool strip_indirection) @@ -1593,7 +1595,7 @@ transformValuesClause(ParseState *pstate, SelectStmt *stmt) * Generate a targetlist as though expanding "*" */ Assert(pstate->p_next_resno == 1); - qry->targetList = expandNSItemAttrs(pstate, nsitem, 0, -1); + qry->targetList = expandNSItemAttrs(pstate, nsitem, 0, true, -1); /* * The grammar allows attaching ORDER BY, LIMIT, and FOR UPDATE to a @@ -2418,9 +2420,9 @@ transformUpdateStmt(ParseState *pstate, UpdateStmt *stmt) /* * transformUpdateTargetList - - * handle SET clause in UPDATE/INSERT ... ON CONFLICT UPDATE + * handle SET clause in UPDATE/MERGE/INSERT ... ON CONFLICT UPDATE */ -static List * +List * transformUpdateTargetList(ParseState *pstate, List *origTlist) { List *tlist = NIL; diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y index c6613af9fe..9399fff610 100644 --- a/src/backend/parser/gram.y +++ b/src/backend/parser/gram.y @@ -278,6 +278,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query); struct SelectLimit *selectlimit; SetQuantifier setquantifier; struct GroupClause *groupclause; + MergeWhenClause *mergewhen; struct KeyActions *keyactions; struct KeyAction *keyaction; } @@ -307,7 +308,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query); DropTransformStmt DropUserMappingStmt ExplainStmt FetchStmt GrantStmt GrantRoleStmt ImportForeignSchemaStmt IndexStmt InsertStmt - ListenStmt LoadStmt LockStmt NotifyStmt ExplainableStmt PreparableStmt + ListenStmt LoadStmt LockStmt MergeStmt NotifyStmt ExplainableStmt PreparableStmt CreateFunctionStmt AlterFunctionStmt ReindexStmt RemoveAggrStmt RemoveFuncStmt RemoveOperStmt RenameStmt ReturnStmt RevokeStmt RevokeRoleStmt RuleActionStmt RuleActionStmtOrEmpty RuleStmt @@ -433,6 +434,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query); any_operator expr_list attrs distinct_clause opt_distinct_clause target_list opt_target_list insert_column_list set_target_list + merge_values_clause set_clause_list set_clause def_list operator_def_list indirection opt_indirection reloption_list TriggerFuncArgs opclass_item_list opclass_drop_list @@ -506,6 +508,10 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query); %type insert_rest %type opt_conf_expr %type opt_on_conflict +%type merge_insert merge_update merge_delete + +%type merge_when_clause opt_merge_when_condition +%type merge_when_list %type generic_set set_rest set_rest_more generic_reset reset_rest SetResetClause FunctionSetResetClause @@ -734,7 +740,8 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query); LEADING LEAKPROOF LEAST LEFT LEVEL LIKE LIMIT LISTEN LOAD LOCAL LOCALTIME LOCALTIMESTAMP LOCATION LOCK_P LOCKED LOGGED - MAPPING MATCH MATERIALIZED MAXVALUE METHOD MINUTE_P MINVALUE MODE MONTH_P MOVE + MAPPING MATCH MATCHED MATERIALIZED MAXVALUE MERGE METHOD + MINUTE_P MINVALUE MODE MONTH_P MOVE NAME_P NAMES NATIONAL NATURAL NCHAR NEW NEXT NFC NFD NFKC NFKD NO NONE NORMALIZE NORMALIZED @@ -1061,6 +1068,7 @@ stmt: | RefreshMatViewStmt | LoadStmt | LockStmt + | MergeStmt | NotifyStmt | PrepareStmt | ReassignOwnedStmt @@ -11123,6 +11131,7 @@ ExplainableStmt: | InsertStmt | UpdateStmt | DeleteStmt + | MergeStmt | DeclareCursorStmt | CreateAsStmt | CreateMatViewStmt @@ -11155,7 +11164,8 @@ PreparableStmt: SelectStmt | InsertStmt | UpdateStmt - | DeleteStmt /* by default all are $$=$1 */ + | DeleteStmt + | MergeStmt /* by default all are $$=$1 */ ; /***************************************************************************** @@ -11540,6 +11550,166 @@ set_target_list: ; +/***************************************************************************** + * + * QUERY: + * MERGE + * + *****************************************************************************/ + +MergeStmt: + opt_with_clause MERGE INTO relation_expr_opt_alias + USING table_ref + ON a_expr + merge_when_list + { + MergeStmt *m = makeNode(MergeStmt); + + m->withClause = $1; + m->relation = $4; + m->sourceRelation = $6; + m->joinCondition = $8; + m->mergeWhenClauses = $9; + + $$ = (Node *)m; + } + ; + +merge_when_list: + merge_when_clause { $$ = list_make1($1); } + | merge_when_list merge_when_clause { $$ = lappend($1,$2); } + ; + +merge_when_clause: + WHEN MATCHED opt_merge_when_condition THEN merge_update + { + $5->matched = true; + $5->condition = $3; + + $$ = (Node *) $5; + } + | WHEN MATCHED opt_merge_when_condition THEN merge_delete + { + $5->matched = true; + $5->condition = $3; + + $$ = (Node *) $5; + } + | WHEN NOT MATCHED opt_merge_when_condition THEN merge_insert + { + $6->matched = false; + $6->condition = $4; + + $$ = (Node *) $6; + } + | WHEN MATCHED opt_merge_when_condition THEN DO NOTHING + { + MergeWhenClause *m = makeNode(MergeWhenClause); + + m->matched = true; + m->commandType = CMD_NOTHING; + m->condition = $3; + + $$ = (Node *)m; + } + | WHEN NOT MATCHED opt_merge_when_condition THEN DO NOTHING + { + MergeWhenClause *m = makeNode(MergeWhenClause); + + m->matched = false; + m->commandType = CMD_NOTHING; + m->condition = $4; + + $$ = (Node *)m; + } + ; + +opt_merge_when_condition: + AND a_expr { $$ = $2; } + | { $$ = NULL; } + ; + +merge_update: + UPDATE SET set_clause_list + { + MergeWhenClause *n = makeNode(MergeWhenClause); + n->commandType = CMD_UPDATE; + n->override = OVERRIDING_NOT_SET; + n->targetList = $3; + n->values = NIL; + + $$ = n; + } + ; + +merge_delete: + DELETE_P + { + MergeWhenClause *n = makeNode(MergeWhenClause); + n->commandType = CMD_DELETE; + n->override = OVERRIDING_NOT_SET; + n->targetList = NIL; + n->values = NIL; + + $$ = n; + } + ; + +merge_insert: + INSERT merge_values_clause + { + MergeWhenClause *n = makeNode(MergeWhenClause); + n->commandType = CMD_INSERT; + n->override = OVERRIDING_NOT_SET; + n->targetList = NIL; + n->values = $2; + $$ = n; + } + | INSERT OVERRIDING override_kind VALUE_P merge_values_clause + { + MergeWhenClause *n = makeNode(MergeWhenClause); + n->commandType = CMD_INSERT; + n->override = $3; + n->targetList = NIL; + n->values = $5; + $$ = n; + } + | INSERT '(' insert_column_list ')' merge_values_clause + { + MergeWhenClause *n = makeNode(MergeWhenClause); + n->commandType = CMD_INSERT; + n->override = OVERRIDING_NOT_SET; + n->targetList = $3; + n->values = $5; + $$ = n; + } + | INSERT '(' insert_column_list ')' OVERRIDING override_kind VALUE_P merge_values_clause + { + MergeWhenClause *n = makeNode(MergeWhenClause); + n->commandType = CMD_INSERT; + n->override = $6; + n->targetList = $3; + n->values = $8; + $$ = n; + } + | INSERT DEFAULT VALUES + { + MergeWhenClause *n = makeNode(MergeWhenClause); + n->commandType = CMD_INSERT; + n->override = OVERRIDING_NOT_SET; + n->targetList = NIL; + n->values = NIL; + $$ = n; + } + ; + +merge_values_clause: + VALUES '(' expr_list ')' + { + $$ = $3; + } + ; + /***************************************************************************** * * QUERY: @@ -16155,8 +16325,10 @@ unreserved_keyword: | LOGGED | MAPPING | MATCH + | MATCHED | MATERIALIZED | MAXVALUE + | MERGE | METHOD | MINUTE_P | MINVALUE @@ -16734,8 +16906,10 @@ bare_label_keyword: | LOGGED | MAPPING | MATCH + | MATCHED | MATERIALIZED | MAXVALUE + | MERGE | METHOD | MINVALUE | MODE diff --git a/src/backend/parser/parse_agg.c b/src/backend/parser/parse_agg.c index ded0a14d72..3ef9e8ee5e 100644 --- a/src/backend/parser/parse_agg.c +++ b/src/backend/parser/parse_agg.c @@ -433,6 +433,13 @@ check_agglevels_and_constraints(ParseState *pstate, Node *expr) case EXPR_KIND_UPDATE_SOURCE: case EXPR_KIND_UPDATE_TARGET: errkind = true; + break; + case EXPR_KIND_MERGE_WHEN: + if (isAgg) + err = _("aggregate functions are not allowed in MERGE WHEN conditions"); + else + err = _("grouping operations are not allowed in MERGE WHEN conditions"); + break; case EXPR_KIND_GROUP_BY: errkind = true; @@ -879,6 +886,9 @@ transformWindowFuncCall(ParseState *pstate, WindowFunc *wfunc, case EXPR_KIND_UPDATE_TARGET: errkind = true; break; + case EXPR_KIND_MERGE_WHEN: + err = _("window functions are not allowed in MERGE WHEN conditions"); + break; case EXPR_KIND_GROUP_BY: errkind = true; break; diff --git a/src/backend/parser/parse_collate.c b/src/backend/parser/parse_collate.c index 6c793b72ec..7582faabb3 100644 --- a/src/backend/parser/parse_collate.c +++ b/src/backend/parser/parse_collate.c @@ -485,6 +485,7 @@ assign_collations_walker(Node *node, assign_collations_context *context) case T_FromExpr: case T_OnConflictExpr: case T_SortGroupClause: + case T_MergeAction: (void) expression_tree_walker(node, assign_collations_walker, (void *) &loccontext); diff --git a/src/backend/parser/parse_expr.c b/src/backend/parser/parse_expr.c index 781c9709e6..84be354f71 100644 --- a/src/backend/parser/parse_expr.c +++ b/src/backend/parser/parse_expr.c @@ -513,6 +513,7 @@ transformColumnRef(ParseState *pstate, ColumnRef *cref) case EXPR_KIND_INSERT_TARGET: case EXPR_KIND_UPDATE_SOURCE: case EXPR_KIND_UPDATE_TARGET: + case EXPR_KIND_MERGE_WHEN: case EXPR_KIND_GROUP_BY: case EXPR_KIND_ORDER_BY: case EXPR_KIND_DISTINCT_ON: @@ -1748,6 +1749,7 @@ transformSubLink(ParseState *pstate, SubLink *sublink) case EXPR_KIND_INSERT_TARGET: case EXPR_KIND_UPDATE_SOURCE: case EXPR_KIND_UPDATE_TARGET: + case EXPR_KIND_MERGE_WHEN: case EXPR_KIND_GROUP_BY: case EXPR_KIND_ORDER_BY: case EXPR_KIND_DISTINCT_ON: @@ -3075,6 +3077,8 @@ ParseExprKindName(ParseExprKind exprKind) case EXPR_KIND_UPDATE_SOURCE: case EXPR_KIND_UPDATE_TARGET: return "UPDATE"; + case EXPR_KIND_MERGE_WHEN: + return "MERGE WHEN"; case EXPR_KIND_GROUP_BY: return "GROUP BY"; case EXPR_KIND_ORDER_BY: diff --git a/src/backend/parser/parse_func.c b/src/backend/parser/parse_func.c index d91951e1f6..f71a682cd6 100644 --- a/src/backend/parser/parse_func.c +++ b/src/backend/parser/parse_func.c @@ -2611,6 +2611,9 @@ check_srf_call_placement(ParseState *pstate, Node *last_srf, int location) /* okay, since we process this like a SELECT tlist */ pstate->p_hasTargetSRFs = true; break; + case EXPR_KIND_MERGE_WHEN: + err = _("set-returning functions are not allowed in MERGE WHEN conditions"); + break; case EXPR_KIND_CHECK_CONSTRAINT: case EXPR_KIND_DOMAIN_CHECK: err = _("set-returning functions are not allowed in check constraints"); diff --git a/src/backend/parser/parse_merge.c b/src/backend/parser/parse_merge.c new file mode 100644 index 0000000000..5d0035a12b --- /dev/null +++ b/src/backend/parser/parse_merge.c @@ -0,0 +1,415 @@ +/*------------------------------------------------------------------------- + * + * parse_merge.c + * handle merge-statement in parser + * + * Portions Copyright (c) 1996-2022, PostgreSQL Global Development Group + * Portions Copyright (c) 1994, Regents of the University of California + * + * + * IDENTIFICATION + * src/backend/parser/parse_merge.c + * + *------------------------------------------------------------------------- + */ + +#include "postgres.h" + +#include "access/sysattr.h" +#include "miscadmin.h" +#include "nodes/makefuncs.h" +#include "nodes/nodeFuncs.h" +#include "parser/analyze.h" +#include "parser/parse_collate.h" +#include "parser/parsetree.h" +#include "parser/parser.h" +#include "parser/parse_clause.h" +#include "parser/parse_cte.h" +#include "parser/parse_expr.h" +#include "parser/parse_merge.h" +#include "parser/parse_relation.h" +#include "parser/parse_target.h" +#include "utils/rel.h" +#include "utils/relcache.h" + +static void setNamespaceForMergeWhen(ParseState *pstate, + MergeWhenClause *mergeWhenClause, + Index targetRTI, + Index sourceRTI); +static void setNamespaceVisibilityForRTE(List *namespace, RangeTblEntry *rte, + bool rel_visible, + bool cols_visible); + +/* + * Make appropriate changes to the namespace visibility while transforming + * individual action's quals and targetlist expressions. In particular, for + * INSERT actions we must only see the source relation (since INSERT action is + * invoked for NOT MATCHED tuples and hence there is no target tuple to deal + * with). On the other hand, UPDATE and DELETE actions can see both source and + * target relations. + * + * Also, since the internal join node can hide the source and target + * relations, we must explicitly make the respective relation as visible so + * that columns can be referenced unqualified from these relations. + */ +static void +setNamespaceForMergeWhen(ParseState *pstate, MergeWhenClause *mergeWhenClause, + Index targetRTI, Index sourceRTI) +{ + RangeTblEntry *targetRelRTE, + *sourceRelRTE; + + targetRelRTE = rt_fetch(targetRTI, pstate->p_rtable); + sourceRelRTE = rt_fetch(sourceRTI, pstate->p_rtable); + + if (mergeWhenClause->matched) + { + Assert(mergeWhenClause->commandType == CMD_UPDATE || + mergeWhenClause->commandType == CMD_DELETE || + mergeWhenClause->commandType == CMD_NOTHING); + + /* MATCHED actions can see both target and source relations. */ + setNamespaceVisibilityForRTE(pstate->p_namespace, + targetRelRTE, true, true); + setNamespaceVisibilityForRTE(pstate->p_namespace, + sourceRelRTE, true, true); + } + else + { + /* + * NOT MATCHED actions can't see target relation, but they can see + * source relation. + */ + Assert(mergeWhenClause->commandType == CMD_INSERT || + mergeWhenClause->commandType == CMD_NOTHING); + setNamespaceVisibilityForRTE(pstate->p_namespace, + targetRelRTE, false, false); + setNamespaceVisibilityForRTE(pstate->p_namespace, + sourceRelRTE, true, true); + } +} + +/* + * transformMergeStmt - + * transforms a MERGE statement + */ +Query * +transformMergeStmt(ParseState *pstate, MergeStmt *stmt) +{ + Query *qry = makeNode(Query); + ListCell *l; + AclMode targetPerms = ACL_NO_RIGHTS; + bool is_terminal[2]; + Index sourceRTI; + List *mergeActionList; + Node *joinExpr; + ParseNamespaceItem *nsitem; + + /* There can't be any outer WITH to worry about */ + Assert(pstate->p_ctenamespace == NIL); + + qry->commandType = CMD_MERGE; + qry->hasRecursive = false; + + /* process the WITH clause independently of all else */ + if (stmt->withClause) + { + if (stmt->withClause->recursive) + ereport(ERROR, + (errcode(ERRCODE_SYNTAX_ERROR), + errmsg("WITH RECURSIVE is not supported for MERGE statement"))); + + qry->cteList = transformWithClause(pstate, stmt->withClause); + qry->hasModifyingCTE = pstate->p_hasModifyingCTE; + } + + /* + * Check WHEN clauses for permissions and sanity + */ + is_terminal[0] = false; + is_terminal[1] = false; + foreach(l, stmt->mergeWhenClauses) + { + MergeWhenClause *mergeWhenClause = (MergeWhenClause *) lfirst(l); + int when_type = (mergeWhenClause->matched ? 0 : 1); + + /* + * Collect action types so we can check target permissions + */ + switch (mergeWhenClause->commandType) + { + case CMD_INSERT: + targetPerms |= ACL_INSERT; + break; + case CMD_UPDATE: + targetPerms |= ACL_UPDATE; + break; + case CMD_DELETE: + targetPerms |= ACL_DELETE; + break; + case CMD_NOTHING: + break; + default: + elog(ERROR, "unknown action in MERGE WHEN clause"); + } + + /* + * Check for unreachable WHEN clauses + */ + if (mergeWhenClause->condition == NULL) + is_terminal[when_type] = true; + else if (is_terminal[when_type]) + ereport(ERROR, + (errcode(ERRCODE_SYNTAX_ERROR), + errmsg("unreachable WHEN clause specified after unconditional WHEN clause"))); + } + + /* Set up the MERGE target table. */ + qry->resultRelation = setTargetTable(pstate, stmt->relation, + stmt->relation->inh, + false, targetPerms); + + /* + * MERGE is unsupported in various cases + */ + if (pstate->p_target_relation->rd_rel->relkind != RELKIND_RELATION && + pstate->p_target_relation->rd_rel->relkind != RELKIND_PARTITIONED_TABLE) + ereport(ERROR, + (errcode(ERRCODE_FEATURE_NOT_SUPPORTED), + errmsg("cannot execute MERGE on relation \"%s\"", + RelationGetRelationName(pstate->p_target_relation)), + errdetail_relkind_not_supported(pstate->p_target_relation->rd_rel->relkind))); + if (pstate->p_target_relation->rd_rel->relhasrules) + ereport(ERROR, + (errcode(ERRCODE_FEATURE_NOT_SUPPORTED), + errmsg("cannot execute MERGE on relation \"%s\"", + RelationGetRelationName(pstate->p_target_relation)), + errdetail("MERGE is not supported for relations with rules."))); + + /* Now transform the source relation to produce the source RTE. */ + transformFromClause(pstate, + list_make1(stmt->sourceRelation)); + sourceRTI = list_length(pstate->p_rtable); + nsitem = GetNSItemByRangeTablePosn(pstate, sourceRTI, 0); + + /* + * Check that the target table doesn't conflict with the source table. + * This would typically be a checkNameSpaceConflicts call, but we want a + * more specific error message. + */ + if (strcmp(pstate->p_target_nsitem->p_names->aliasname, + nsitem->p_names->aliasname) == 0) + ereport(ERROR, + errcode(ERRCODE_DUPLICATE_ALIAS), + errmsg("name \"%s\" specified more than once", + pstate->p_target_nsitem->p_names->aliasname), + errdetail("The name is used both as MERGE target table and data source.")); + + qry->targetList = expandNSItemAttrs(pstate, nsitem, 0, false, + exprLocation(stmt->sourceRelation)); + + qry->rtable = pstate->p_rtable; + + /* + * Transform the join condition. This includes references to the target + * side, so add that to the namespace. + */ + addNSItemToQuery(pstate, pstate->p_target_nsitem, false, true, true); + joinExpr = transformExpr(pstate, stmt->joinCondition, + EXPR_KIND_JOIN_ON); + + /* + * Create the temporary query's jointree using the joinlist we built using + * just the source relation; the target relation is not included. The + * quals we use are the join conditions to the merge target. The join + * will be constructed fully by transform_MERGE_to_join. + */ + qry->jointree = makeFromExpr(pstate->p_joinlist, joinExpr); + + /* + * We now have a good query shape, so now look at the WHEN conditions and + * action targetlists. + * + * Overall, the MERGE Query's targetlist is NIL. + * + * Each individual action has its own targetlist that needs separate + * transformation. These transforms don't do anything to the overall + * targetlist, since that is only used for resjunk columns. + * + * We can reference any column in Target or Source, which is OK because + * both of those already have RTEs. There is nothing like the EXCLUDED + * pseudo-relation for INSERT ON CONFLICT. + */ + mergeActionList = NIL; + foreach(l, stmt->mergeWhenClauses) + { + MergeWhenClause *mergeWhenClause = lfirst_node(MergeWhenClause, l); + MergeAction *action; + + action = makeNode(MergeAction); + action->commandType = mergeWhenClause->commandType; + action->matched = mergeWhenClause->matched; + + /* Use an outer join if any INSERT actions exist in the command. */ + if (action->commandType == CMD_INSERT) + qry->mergeUseOuterJoin = true; + + /* + * Set namespace for the specific action. This must be done before + * analyzing the WHEN quals and the action targetlist. + */ + setNamespaceForMergeWhen(pstate, mergeWhenClause, + qry->resultRelation, + sourceRTI); + + /* + * Transform the WHEN condition. + * + * Note that these quals are NOT added to the join quals; instead they + * are evaluated separately during execution to decide which of the + * WHEN MATCHED or WHEN NOT MATCHED actions to execute. + */ + action->qual = transformWhereClause(pstate, mergeWhenClause->condition, + EXPR_KIND_MERGE_WHEN, "WHEN"); + + /* + * Transform target lists for each INSERT and UPDATE action stmt + */ + switch (action->commandType) + { + case CMD_INSERT: + { + List *exprList = NIL; + ListCell *lc; + RangeTblEntry *rte; + ListCell *icols; + ListCell *attnos; + List *icolumns; + List *attrnos; + + pstate->p_is_insert = true; + + icolumns = checkInsertTargets(pstate, + mergeWhenClause->targetList, + &attrnos); + Assert(list_length(icolumns) == list_length(attrnos)); + + action->override = mergeWhenClause->override; + + /* + * Handle INSERT much like in transformInsertStmt + */ + if (mergeWhenClause->values == NIL) + { + /* + * We have INSERT ... DEFAULT VALUES. We can handle + * this case by emitting an empty targetlist --- all + * columns will be defaulted when the planner expands + * the targetlist. + */ + exprList = NIL; + } + else + { + /* + * Process INSERT ... VALUES with a single VALUES + * sublist. We treat this case separately for + * efficiency. The sublist is just computed directly + * as the Query's targetlist, with no VALUES RTE. So + * it works just like a SELECT without any FROM. + */ + + /* + * Do basic expression transformation (same as a ROW() + * expr, but allow SetToDefault at top level) + */ + exprList = transformExpressionList(pstate, + mergeWhenClause->values, + EXPR_KIND_VALUES_SINGLE, + true); + + /* Prepare row for assignment to target table */ + exprList = transformInsertRow(pstate, exprList, + mergeWhenClause->targetList, + icolumns, attrnos, + false); + } + + /* + * Generate action's target list using the computed list + * of expressions. Also, mark all the target columns as + * needing insert permissions. + */ + rte = pstate->p_target_nsitem->p_rte; + forthree(lc, exprList, icols, icolumns, attnos, attrnos) + { + Expr *expr = (Expr *) lfirst(lc); + ResTarget *col = lfirst_node(ResTarget, icols); + AttrNumber attr_num = (AttrNumber) lfirst_int(attnos); + TargetEntry *tle; + + tle = makeTargetEntry(expr, + attr_num, + col->name, + false); + action->targetList = lappend(action->targetList, tle); + + rte->insertedCols = + bms_add_member(rte->insertedCols, + attr_num - FirstLowInvalidHeapAttributeNumber); + } + } + break; + case CMD_UPDATE: + { + pstate->p_is_insert = false; + action->targetList = + transformUpdateTargetList(pstate, + mergeWhenClause->targetList); + } + break; + case CMD_DELETE: + break; + + case CMD_NOTHING: + action->targetList = NIL; + break; + default: + elog(ERROR, "unknown action in MERGE WHEN clause"); + } + + mergeActionList = lappend(mergeActionList, action); + } + + qry->mergeActionList = mergeActionList; + + /* RETURNING could potentially be added in the future, but not in SQL std */ + qry->returningList = NULL; + + qry->hasTargetSRFs = false; + qry->hasSubLinks = pstate->p_hasSubLinks; + + assign_query_collations(pstate, qry); + + return qry; +} + +static void +setNamespaceVisibilityForRTE(List *namespace, RangeTblEntry *rte, + bool rel_visible, + bool cols_visible) +{ + ListCell *lc; + + foreach(lc, namespace) + { + ParseNamespaceItem *nsitem = (ParseNamespaceItem *) lfirst(lc); + + if (nsitem->p_rte == rte) + { + nsitem->p_rel_visible = rel_visible; + nsitem->p_cols_visible = cols_visible; + break; + } + } +} diff --git a/src/backend/parser/parse_relation.c b/src/backend/parser/parse_relation.c index cb9e177b5e..7efa5f15d7 100644 --- a/src/backend/parser/parse_relation.c +++ b/src/backend/parser/parse_relation.c @@ -701,6 +701,17 @@ scanNSItemForColumn(ParseState *pstate, ParseNamespaceItem *nsitem, colname), parser_errposition(pstate, location))); + /* + * In a MERGE WHEN condition, no system column is allowed except tableOid + */ + if (pstate->p_expr_kind == EXPR_KIND_MERGE_WHEN && + attnum < InvalidAttrNumber && attnum != TableOidAttributeNumber) + ereport(ERROR, + (errcode(ERRCODE_INVALID_COLUMN_REFERENCE), + errmsg("cannot use system column \"%s\" in MERGE WHEN condition", + colname), + parser_errposition(pstate, location))); + /* Found a valid match, so build a Var */ if (attnum > InvalidAttrNumber) { @@ -3095,11 +3106,12 @@ expandNSItemVars(ParseNamespaceItem *nsitem, * for the attributes of the nsitem * * pstate->p_next_resno determines the resnos assigned to the TLEs. - * The referenced columns are marked as requiring SELECT access. + * The referenced columns are marked as requiring SELECT access, if + * caller requests that. */ List * expandNSItemAttrs(ParseState *pstate, ParseNamespaceItem *nsitem, - int sublevels_up, int location) + int sublevels_up, bool require_col_privs, int location) { RangeTblEntry *rte = nsitem->p_rte; List *names, @@ -3133,8 +3145,11 @@ expandNSItemAttrs(ParseState *pstate, ParseNamespaceItem *nsitem, false); te_list = lappend(te_list, te); - /* Require read access to each column */ - markVarForSelectPriv(pstate, varnode); + if (require_col_privs) + { + /* Require read access to each column */ + markVarForSelectPriv(pstate, varnode); + } } Assert(name == NULL && var == NULL); /* lists not the same length? */ diff --git a/src/backend/parser/parse_target.c b/src/backend/parser/parse_target.c index 204d285773..e6445c7baf 100644 --- a/src/backend/parser/parse_target.c +++ b/src/backend/parser/parse_target.c @@ -1308,6 +1308,7 @@ ExpandAllTables(ParseState *pstate, int location) expandNSItemAttrs(pstate, nsitem, 0, + true, location)); } @@ -1370,7 +1371,7 @@ ExpandSingleTable(ParseState *pstate, ParseNamespaceItem *nsitem, if (make_target_entry) { /* expandNSItemAttrs handles permissions marking */ - return expandNSItemAttrs(pstate, nsitem, sublevels_up, location); + return expandNSItemAttrs(pstate, nsitem, sublevels_up, true, location); } else { diff --git a/src/backend/rewrite/rewriteHandler.c b/src/backend/rewrite/rewriteHandler.c index 4eeed580b1..29ae27e5e3 100644 --- a/src/backend/rewrite/rewriteHandler.c +++ b/src/backend/rewrite/rewriteHandler.c @@ -1643,6 +1643,10 @@ matchLocks(CmdType event, if (rulelocks == NULL) return NIL; + /* No rule support for MERGE */ + if (parsetree->commandType == CMD_MERGE) + return NIL; + if (parsetree->commandType != CMD_SELECT) { if (parsetree->resultRelation != varno) @@ -3671,8 +3675,8 @@ RewriteQuery(Query *parsetree, List *rewrite_events) } /* - * If the statement is an insert, update, or delete, adjust its targetlist - * as needed, and then fire INSERT/UPDATE/DELETE rules on it. + * If the statement is an insert, update, delete, or merge, adjust its + * targetlist as needed, and then fire INSERT/UPDATE/DELETE rules on it. * * SELECT rules are handled later when we have all the queries that should * get executed. Also, utilities aren't rewritten at all (do we still @@ -3770,6 +3774,7 @@ RewriteQuery(Query *parsetree, List *rewrite_events) } else if (event == CMD_UPDATE) { + Assert(parsetree->override == OVERRIDING_NOT_SET); parsetree->targetList = rewriteTargetListIU(parsetree->targetList, parsetree->commandType, @@ -3780,6 +3785,38 @@ RewriteQuery(Query *parsetree, List *rewrite_events) /* Also populate extraUpdatedCols (for generated columns) */ fill_extraUpdatedCols(rt_entry, rt_entry_relation); } + else if (event == CMD_MERGE) + { + Assert(parsetree->override == OVERRIDING_NOT_SET); + + /* + * Rewrite each action targetlist separately + */ + foreach(lc1, parsetree->mergeActionList) + { + MergeAction *action = (MergeAction *) lfirst(lc1); + + switch (action->commandType) + { + case CMD_NOTHING: + case CMD_DELETE: /* Nothing to do here */ + break; + case CMD_UPDATE: + case CMD_INSERT: + /* XXX is it possible to have a VALUES clause? */ + action->targetList = + rewriteTargetListIU(action->targetList, + action->commandType, + action->override, + rt_entry_relation, + NULL, 0, NULL); + break; + default: + elog(ERROR, "unrecognized commandType: %d", action->commandType); + break; + } + } + } else if (event == CMD_DELETE) { /* Nothing to do here */ diff --git a/src/backend/rewrite/rowsecurity.c b/src/backend/rewrite/rowsecurity.c index f0a046d65a..a233dd4758 100644 --- a/src/backend/rewrite/rowsecurity.c +++ b/src/backend/rewrite/rowsecurity.c @@ -232,15 +232,17 @@ get_row_security_policies(Query *root, RangeTblEntry *rte, int rt_index, hasSubLinks); /* - * Similar to above, during an UPDATE or DELETE, if SELECT rights are also - * required (eg: when a RETURNING clause exists, or the user has provided - * a WHERE clause which involves columns from the relation), we collect up - * CMD_SELECT policies and add them via add_security_quals first. + * Similar to above, during an UPDATE, DELETE, or MERGE, if SELECT rights + * are also required (eg: when a RETURNING clause exists, or the user has + * provided a WHERE clause which involves columns from the relation), we + * collect up CMD_SELECT policies and add them via add_security_quals + * first. * * This way, we filter out any records which are not visible through an * ALL or SELECT USING policy. */ - if ((commandType == CMD_UPDATE || commandType == CMD_DELETE) && + if ((commandType == CMD_UPDATE || commandType == CMD_DELETE || + commandType == CMD_MERGE) && rte->requiredPerms & ACL_SELECT) { List *select_permissive_policies; @@ -380,6 +382,92 @@ get_row_security_policies(Query *root, RangeTblEntry *rte, int rt_index, } } + /* + * FOR MERGE, we fetch policies for UPDATE, DELETE and INSERT (and ALL) + * and set them up so that we can enforce the appropriate policy depending + * on the final action we take. + * + * We already fetched the SELECT policies above. + * + * We don't push the UPDATE/DELETE USING quals to the RTE because we don't + * really want to apply them while scanning the relation since we don't + * know whether we will be doing an UPDATE or a DELETE at the end. We + * apply the respective policy once we decide the final action on the + * target tuple. + * + * XXX We are setting up USING quals as WITH CHECK. If RLS prohibits + * UPDATE/DELETE on the target row, we shall throw an error instead of + * silently ignoring the row. This is different than how normal + * UPDATE/DELETE works and more in line with INSERT ON CONFLICT DO UPDATE + * handling. + */ + if (commandType == CMD_MERGE) + { + List *merge_permissive_policies; + List *merge_restrictive_policies; + + /* + * Fetch the UPDATE policies and set them up to execute on the + * existing target row before doing UPDATE. + */ + get_policies_for_relation(rel, CMD_UPDATE, user_id, + &merge_permissive_policies, + &merge_restrictive_policies); + + /* + * WCO_RLS_MERGE_UPDATE_CHECK is used to check UPDATE USING quals on + * the existing target row. + */ + add_with_check_options(rel, rt_index, + WCO_RLS_MERGE_UPDATE_CHECK, + merge_permissive_policies, + merge_restrictive_policies, + withCheckOptions, + hasSubLinks, + true); + + /* + * Same with DELETE policies. + */ + get_policies_for_relation(rel, CMD_DELETE, user_id, + &merge_permissive_policies, + &merge_restrictive_policies); + + add_with_check_options(rel, rt_index, + WCO_RLS_MERGE_DELETE_CHECK, + merge_permissive_policies, + merge_restrictive_policies, + withCheckOptions, + hasSubLinks, + true); + + /* + * No special handling is required for INSERT policies. They will be + * checked and enforced during ExecInsert(). But we must add them to + * withCheckOptions. + */ + get_policies_for_relation(rel, CMD_INSERT, user_id, + &merge_permissive_policies, + &merge_restrictive_policies); + + add_with_check_options(rel, rt_index, + WCO_RLS_INSERT_CHECK, + merge_permissive_policies, + merge_restrictive_policies, + withCheckOptions, + hasSubLinks, + false); + + /* Enforce the WITH CHECK clauses of the UPDATE policies */ + add_with_check_options(rel, rt_index, + WCO_RLS_UPDATE_CHECK, + merge_permissive_policies, + merge_restrictive_policies, + withCheckOptions, + hasSubLinks, + false); + } + table_close(rel, NoLock); /* @@ -444,6 +532,14 @@ get_policies_for_relation(Relation relation, CmdType cmd, Oid user_id, if (policy->polcmd == ACL_DELETE_CHR) cmd_matches = true; break; + case CMD_MERGE: + + /* + * We do not support a separate policy for MERGE command. + * Instead it derives from the policies defined for other + * commands. + */ + break; default: elog(ERROR, "unrecognized policy command type %d", (int) cmd); diff --git a/src/backend/tcop/pquery.c b/src/backend/tcop/pquery.c index 5f907831a3..5aa5a350f3 100644 --- a/src/backend/tcop/pquery.c +++ b/src/backend/tcop/pquery.c @@ -178,6 +178,9 @@ ProcessQuery(PlannedStmt *plan, case CMD_DELETE: SetQueryCompletion(qc, CMDTAG_DELETE, queryDesc->estate->es_processed); break; + case CMD_MERGE: + SetQueryCompletion(qc, CMDTAG_MERGE, queryDesc->estate->es_processed); + break; default: SetQueryCompletion(qc, CMDTAG_UNKNOWN, queryDesc->estate->es_processed); break; diff --git a/src/backend/tcop/utility.c b/src/backend/tcop/utility.c index 3780c6e812..f364a9b88a 100644 --- a/src/backend/tcop/utility.c +++ b/src/backend/tcop/utility.c @@ -113,6 +113,7 @@ CommandIsReadOnly(PlannedStmt *pstmt) case CMD_UPDATE: case CMD_INSERT: case CMD_DELETE: + case CMD_MERGE: return false; case CMD_UTILITY: /* For now, treat all utility commands as read/write */ @@ -2124,6 +2125,8 @@ QueryReturnsTuples(Query *parsetree) case CMD_SELECT: /* returns tuples */ return true; + case CMD_MERGE: + return false; case CMD_INSERT: case CMD_UPDATE: case CMD_DELETE: @@ -2365,6 +2368,10 @@ CreateCommandTag(Node *parsetree) tag = CMDTAG_UPDATE; break; + case T_MergeStmt: + tag = CMDTAG_MERGE; + break; + case T_SelectStmt: tag = CMDTAG_SELECT; break; @@ -3125,6 +3132,9 @@ CreateCommandTag(Node *parsetree) case CMD_DELETE: tag = CMDTAG_DELETE; break; + case CMD_MERGE: + tag = CMDTAG_MERGE; + break; case CMD_UTILITY: tag = CreateCommandTag(stmt->utilityStmt); break; @@ -3185,6 +3195,9 @@ CreateCommandTag(Node *parsetree) case CMD_DELETE: tag = CMDTAG_DELETE; break; + case CMD_MERGE: + tag = CMDTAG_MERGE; + break; case CMD_UTILITY: tag = CreateCommandTag(stmt->utilityStmt); break; @@ -3233,6 +3246,7 @@ GetCommandLogLevel(Node *parsetree) case T_InsertStmt: case T_DeleteStmt: case T_UpdateStmt: + case T_MergeStmt: lev = LOGSTMT_MOD; break; @@ -3682,6 +3696,7 @@ GetCommandLogLevel(Node *parsetree) case CMD_UPDATE: case CMD_INSERT: case CMD_DELETE: + case CMD_MERGE: lev = LOGSTMT_MOD; break; @@ -3712,6 +3727,7 @@ GetCommandLogLevel(Node *parsetree) case CMD_UPDATE: case CMD_INSERT: case CMD_DELETE: + case CMD_MERGE: lev = LOGSTMT_MOD; break; diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c index df5c486501..82dc849a30 100644 --- a/src/backend/utils/adt/ruleutils.c +++ b/src/backend/utils/adt/ruleutils.c @@ -4940,6 +4940,8 @@ set_deparse_plan(deparse_namespace *dpns, Plan *plan) * For a WorkTableScan, locate the parent RecursiveUnion plan node and use * that as INNER referent. * + * For MERGE, make the inner tlist point to the merge source tlist, which + * is same as the targetlist that the ModifyTable's source plan provides. * For ON CONFLICT .. UPDATE we just need the inner tlist to point to the * excluded expression's tlist. (Similar to the SubqueryScan we don't want * to reuse OUTER, it's used for RETURNING in some modify table cases, @@ -4959,7 +4961,12 @@ set_deparse_plan(deparse_namespace *dpns, Plan *plan) dpns->inner_plan = innerPlan(plan); if (IsA(plan, ModifyTable)) - dpns->inner_tlist = ((ModifyTable *) plan)->exclRelTlist; + { + if (((ModifyTable *) plan)->operation == CMD_MERGE) + dpns->inner_tlist = dpns->outer_plan->targetlist; + else + dpns->inner_tlist = ((ModifyTable *) plan)->exclRelTlist; + } else if (dpns->inner_plan) dpns->inner_tlist = dpns->inner_plan->targetlist; else diff --git a/src/bin/psql/tab-complete.c b/src/bin/psql/tab-complete.c index 63bfdf11c6..c97d3e87f0 100644 --- a/src/bin/psql/tab-complete.c +++ b/src/bin/psql/tab-complete.c @@ -820,6 +820,17 @@ static const SchemaQuery Query_for_list_of_updatables = { .result = "c.relname", }; +/* Relations supporting MERGE */ +static const SchemaQuery Query_for_list_of_mergetargets = { + .catname = "pg_catalog.pg_class c", + .selcondition = + "c.relkind IN (" CppAsString2(RELKIND_RELATION) ", " + CppAsString2(RELKIND_PARTITIONED_TABLE) ") ", + .viscondition = "pg_catalog.pg_table_is_visible(c.oid)", + .namespace = "c.relnamespace", + .result = "c.relname", +}; + /* Relations supporting SELECT */ static const SchemaQuery Query_for_list_of_selectables = { .catname = "pg_catalog.pg_class c", @@ -1664,7 +1675,7 @@ psql_completion(const char *text, int start, int end) "COMMENT", "COMMIT", "COPY", "CREATE", "DEALLOCATE", "DECLARE", "DELETE FROM", "DISCARD", "DO", "DROP", "END", "EXECUTE", "EXPLAIN", "FETCH", "GRANT", "IMPORT FOREIGN SCHEMA", "INSERT INTO", "LISTEN", "LOAD", "LOCK", - "MOVE", "NOTIFY", "PREPARE", + "MERGE", "MOVE", "NOTIFY", "PREPARE", "REASSIGN", "REFRESH MATERIALIZED VIEW", "REINDEX", "RELEASE", "RESET", "REVOKE", "ROLLBACK", "SAVEPOINT", "SECURITY LABEL", "SELECT", "SET", "SHOW", "START", @@ -3627,7 +3638,7 @@ psql_completion(const char *text, int start, int end) */ else if (Matches("EXPLAIN")) COMPLETE_WITH("SELECT", "INSERT INTO", "DELETE FROM", "UPDATE", "DECLARE", - "EXECUTE", "ANALYZE", "VERBOSE"); + "MERGE", "EXECUTE", "ANALYZE", "VERBOSE"); else if (HeadMatches("EXPLAIN", "(*") && !HeadMatches("EXPLAIN", "(*)")) { @@ -3646,12 +3657,12 @@ psql_completion(const char *text, int start, int end) } else if (Matches("EXPLAIN", "ANALYZE")) COMPLETE_WITH("SELECT", "INSERT INTO", "DELETE FROM", "UPDATE", "DECLARE", - "EXECUTE", "VERBOSE"); + "MERGE", "EXECUTE", "VERBOSE"); else if (Matches("EXPLAIN", "(*)") || Matches("EXPLAIN", "VERBOSE") || Matches("EXPLAIN", "ANALYZE", "VERBOSE")) COMPLETE_WITH("SELECT", "INSERT INTO", "DELETE FROM", "UPDATE", "DECLARE", - "EXECUTE"); + "MERGE", "EXECUTE"); /* FETCH && MOVE */ @@ -3913,6 +3924,9 @@ psql_completion(const char *text, int start, int end) COMPLETE_WITH("OPTIONS ("); /* INSERT --- can be inside EXPLAIN, RULE, etc */ + /* Complete NOT MATCHED THEN INSERT */ + else if (TailMatches("NOT", "MATCHED", "THEN", "INSERT")) + COMPLETE_WITH("VALUES", "("); /* Complete INSERT with "INTO" */ else if (TailMatches("INSERT")) COMPLETE_WITH("INTO"); @@ -3988,6 +4002,53 @@ psql_completion(const char *text, int start, int end) else if (HeadMatches("LOCK") && TailMatches("IN", "SHARE")) COMPLETE_WITH("MODE", "ROW EXCLUSIVE MODE", "UPDATE EXCLUSIVE MODE"); +/* MERGE --- can be inside EXPLAIN */ + else if (TailMatches("MERGE")) + COMPLETE_WITH("INTO"); + else if (TailMatches("MERGE", "INTO")) + COMPLETE_WITH_SCHEMA_QUERY(Query_for_list_of_mergetargets); + else if (TailMatches("MERGE", "INTO", MatchAny)) + COMPLETE_WITH("USING", "AS"); + else if (TailMatches("MERGE", "INTO", MatchAny, "USING")) + COMPLETE_WITH_SCHEMA_QUERY(Query_for_list_of_tables); + /* with [AS] alias */ + else if (TailMatches("MERGE", "INTO", MatchAny, "AS", MatchAny)) + COMPLETE_WITH("USING"); + else if (TailMatches("MERGE", "INTO", MatchAny, MatchAny)) + COMPLETE_WITH("USING"); + else if (TailMatches("MERGE", "INTO", MatchAny, "AS", MatchAny, "USING")) + COMPLETE_WITH_SCHEMA_QUERY(Query_for_list_of_tables); + else if (TailMatches("MERGE", "INTO", MatchAny, MatchAny, "USING")) + COMPLETE_WITH_SCHEMA_QUERY(Query_for_list_of_tables); + /* ON */ + else if (TailMatches("MERGE", "INTO", MatchAny, "USING", MatchAny)) + COMPLETE_WITH("ON"); + else if (TailMatches("INTO", MatchAny, "AS", MatchAny, "USING", MatchAny, "AS", MatchAny)) + COMPLETE_WITH("ON"); + else if (TailMatches("INTO", MatchAny, MatchAny, "USING", MatchAny, MatchAny)) + COMPLETE_WITH("ON"); + /* ON condition */ + else if (TailMatches("INTO", MatchAny, "USING", MatchAny, "ON")) + COMPLETE_WITH_ATTR(prev4_wd); + else if (TailMatches("INTO", MatchAny, "AS", MatchAny, "USING", MatchAny, "AS", MatchAny, "ON")) + COMPLETE_WITH_ATTR(prev8_wd); + else if (TailMatches("INTO", MatchAny, MatchAny, "USING", MatchAny, MatchAny, "ON")) + COMPLETE_WITH_ATTR(prev6_wd); + /* WHEN [NOT] MATCHED */ + else if (TailMatches("USING", MatchAny, "ON", MatchAny)) + COMPLETE_WITH("WHEN MATCHED", "WHEN NOT MATCHED"); + else if (TailMatches("USING", MatchAny, "AS", MatchAny, "ON", MatchAny)) + COMPLETE_WITH("WHEN MATCHED", "WHEN NOT MATCHED"); + else if (TailMatches("USING", MatchAny, MatchAny, "ON", MatchAny)) + COMPLETE_WITH("WHEN MATCHED", "WHEN NOT MATCHED"); + else if (TailMatches("WHEN", "MATCHED")) + COMPLETE_WITH("THEN", "AND"); + else if (TailMatches("WHEN", "NOT", "MATCHED")) + COMPLETE_WITH("THEN", "AND"); + else if (TailMatches("WHEN", "MATCHED", "THEN")) + COMPLETE_WITH("UPDATE", "DELETE"); + else if (TailMatches("WHEN", "NOT", "MATCHED", "THEN")) + COMPLETE_WITH("INSERT", "DO NOTHING"); /* Complete LOCK [TABLE] [ONLY] [IN lockmode MODE] with "NOWAIT" */ else if (HeadMatches("LOCK") && TailMatches("MODE")) diff --git a/src/include/commands/trigger.h b/src/include/commands/trigger.h index 66bf6c16e3..194e8d5bc1 100644 --- a/src/include/commands/trigger.h +++ b/src/include/commands/trigger.h @@ -13,6 +13,7 @@ #ifndef TRIGGER_H #define TRIGGER_H +#include "access/tableam.h" #include "catalog/objectaddress.h" #include "nodes/execnodes.h" #include "nodes/parsenodes.h" @@ -229,7 +230,8 @@ extern bool ExecBRUpdateTriggers(EState *estate, ResultRelInfo *relinfo, ItemPointer tupleid, HeapTuple fdw_trigtuple, - TupleTableSlot *slot); + TupleTableSlot *slot, + TM_FailureData *tmfdp); extern void ExecARUpdateTriggers(EState *estate, ResultRelInfo *relinfo, ResultRelInfo *src_partinfo, diff --git a/src/include/executor/nodeModifyTable.h b/src/include/executor/nodeModifyTable.h index 1d225bc88d..c318681b9a 100644 --- a/src/include/executor/nodeModifyTable.h +++ b/src/include/executor/nodeModifyTable.h @@ -23,4 +23,7 @@ extern ModifyTableState *ExecInitModifyTable(ModifyTable *node, EState *estate, extern void ExecEndModifyTable(ModifyTableState *node); extern void ExecReScanModifyTable(ModifyTableState *node); +extern void ExecInitMergeTupleSlots(ModifyTableState *mtstate, + ResultRelInfo *resultRelInfo); + #endif /* NODEMODIFYTABLE_H */ diff --git a/src/include/executor/spi.h b/src/include/executor/spi.h index 6ec3851444..b2c0c7486c 100644 --- a/src/include/executor/spi.h +++ b/src/include/executor/spi.h @@ -96,6 +96,7 @@ typedef struct _SPI_plan *SPIPlanPtr; #define SPI_OK_REL_REGISTER 15 #define SPI_OK_REL_UNREGISTER 16 #define SPI_OK_TD_REGISTER 17 +#define SPI_OK_MERGE 18 #define SPI_OPT_NONATOMIC (1 << 0) diff --git a/src/include/nodes/execnodes.h b/src/include/nodes/execnodes.h index 44dd73fc80..cbbcff81d2 100644 --- a/src/include/nodes/execnodes.h +++ b/src/include/nodes/execnodes.h @@ -389,6 +389,22 @@ typedef struct OnConflictSetState ExprState *oc_WhereClause; /* state for the WHERE clause */ } OnConflictSetState; +/* ---------------- + * MergeActionState information + * + * Executor state for a MERGE action. + * ---------------- + */ +typedef struct MergeActionState +{ + NodeTag type; + + MergeAction *mas_action; /* associated MergeAction node */ + ProjectionInfo *mas_proj; /* projection of the action's targetlist for + * this rel */ + ExprState *mas_whenqual; /* WHEN [NOT] MATCHED AND conditions */ +} MergeActionState; + /* * ResultRelInfo * @@ -500,6 +516,10 @@ typedef struct ResultRelInfo /* ON CONFLICT evaluation state */ OnConflictSetState *ri_onConflict; + /* for MERGE, lists of MergeActionState */ + List *ri_matchedMergeAction; + List *ri_notMatchedMergeAction; + /* partition check expression state (NULL if not set up yet) */ ExprState *ri_PartitionCheckExpr; @@ -1190,6 +1210,12 @@ typedef struct ProjectSetState MemoryContext argcontext; /* context for SRF arguments */ } ProjectSetState; + +/* flags for mt_merge_subcommands */ +#define MERGE_INSERT 0x01 +#define MERGE_UPDATE 0x02 +#define MERGE_DELETE 0x04 + /* ---------------- * ModifyTableState information * ---------------- @@ -1197,7 +1223,7 @@ typedef struct ProjectSetState typedef struct ModifyTableState { PlanState ps; /* its first field is NodeTag */ - CmdType operation; /* INSERT, UPDATE, or DELETE */ + CmdType operation; /* INSERT, UPDATE, DELETE, or MERGE */ bool canSetTag; /* do we set the command tag/es_processed? */ bool mt_done; /* are we done? */ int mt_nrels; /* number of entries in resultRelInfo[] */ @@ -1239,6 +1265,14 @@ typedef struct ModifyTableState /* controls transition table population for INSERT...ON CONFLICT UPDATE */ struct TransitionCaptureState *mt_oc_transition_capture; + + /* Flags showing which subcommands are present INS/UPD/DEL/DO NOTHING */ + int mt_merge_subcommands; + + /* tuple counters for MERGE */ + double mt_merge_inserted; + double mt_merge_updated; + double mt_merge_deleted; } ModifyTableState; /* ---------------- diff --git a/src/include/nodes/nodes.h b/src/include/nodes/nodes.h index 05f0b79e82..ca440eb75f 100644 --- a/src/include/nodes/nodes.h +++ b/src/include/nodes/nodes.h @@ -35,6 +35,7 @@ typedef enum NodeTag T_ProjectionInfo, T_JunkFilter, T_OnConflictSetState, + T_MergeActionState, T_ResultRelInfo, T_EState, T_TupleTableSlot, @@ -283,6 +284,7 @@ typedef enum NodeTag T_RollupData, T_GroupingSetData, T_StatisticExtInfo, + T_MergeAction, /* * TAGS FOR MEMORY NODES (memnodes.h) @@ -321,6 +323,7 @@ typedef enum NodeTag T_InsertStmt, T_DeleteStmt, T_UpdateStmt, + T_MergeStmt, T_SelectStmt, T_ReturnStmt, T_PLAssignStmt, @@ -485,6 +488,7 @@ typedef enum NodeTag T_CTESearchClause, T_CTECycleClause, T_CommonTableExpr, + T_MergeWhenClause, T_RoleSpec, T_TriggerTransition, T_PartitionElem, @@ -698,7 +702,8 @@ typedef enum CmdType CMD_SELECT, /* select stmt */ CMD_UPDATE, /* update stmt */ CMD_INSERT, /* insert stmt */ - CMD_DELETE, + CMD_DELETE, /* delete stmt */ + CMD_MERGE, /* merge stmt */ CMD_UTILITY, /* cmds like create, destroy, copy, vacuum, * etc. */ CMD_NOTHING /* dummy command for instead nothing rules diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h index 3b12a708ec..6bf212b01a 100644 --- a/src/include/nodes/parsenodes.h +++ b/src/include/nodes/parsenodes.h @@ -119,7 +119,7 @@ typedef struct Query { NodeTag type; - CmdType commandType; /* select|insert|update|delete|utility */ + CmdType commandType; /* select|insert|update|delete|merge|utility */ QuerySource querySource; /* where did I come from? */ @@ -130,7 +130,7 @@ typedef struct Query Node *utilityStmt; /* non-null if commandType == CMD_UTILITY */ int resultRelation; /* rtable index of target relation for - * INSERT/UPDATE/DELETE; 0 for SELECT */ + * INSERT/UPDATE/DELETE/MERGE; 0 for SELECT */ bool hasAggs; /* has aggregates in tlist or havingQual */ bool hasWindowFuncs; /* has window functions in tlist */ @@ -147,7 +147,11 @@ typedef struct Query List *cteList; /* WITH list (of CommonTableExpr's) */ List *rtable; /* list of range table entries */ - FromExpr *jointree; /* table join tree (FROM and WHERE clauses) */ + FromExpr *jointree; /* table join tree (FROM and WHERE clauses); + * also USING clause for MERGE */ + + List *mergeActionList; /* list of actions for MERGE (only) */ + bool mergeUseOuterJoin; /* whether to use outer join */ List *targetList; /* target list (of TargetEntry) */ @@ -1221,7 +1225,9 @@ typedef enum WCOKind WCO_VIEW_CHECK, /* WCO on an auto-updatable view */ WCO_RLS_INSERT_CHECK, /* RLS INSERT WITH CHECK policy */ WCO_RLS_UPDATE_CHECK, /* RLS UPDATE WITH CHECK policy */ - WCO_RLS_CONFLICT_CHECK /* RLS ON CONFLICT DO UPDATE USING policy */ + WCO_RLS_CONFLICT_CHECK, /* RLS ON CONFLICT DO UPDATE USING policy */ + WCO_RLS_MERGE_UPDATE_CHECK, /* RLS MERGE UPDATE USING policy */ + WCO_RLS_MERGE_DELETE_CHECK /* RLS MERGE DELETE USING policy */ } WCOKind; typedef struct WithCheckOption @@ -1537,6 +1543,39 @@ typedef struct CommonTableExpr ((Query *) (cte)->ctequery)->targetList : \ ((Query *) (cte)->ctequery)->returningList) +/* + * MergeWhenClause - + * raw parser representation of a WHEN clause in a MERGE statement + * + * This is transformed into MergeAction by parse analysis + */ +typedef struct MergeWhenClause +{ + NodeTag type; + bool matched; /* true=MATCHED, false=NOT MATCHED */ + CmdType commandType; /* INSERT/UPDATE/DELETE/DO NOTHING */ + OverridingKind override; /* OVERRIDING clause */ + Node *condition; /* WHEN conditions (raw parser) */ + List *targetList; /* INSERT/UPDATE targetlist */ + /* the following members are only used in INSERT actions */ + List *values; /* VALUES to INSERT, or NULL */ +} MergeWhenClause; + +/* + * MergeAction - + * Transformed representation of a WHEN clause in a MERGE statement + */ +typedef struct MergeAction +{ + NodeTag type; + bool matched; /* true=MATCHED, false=NOT MATCHED */ + CmdType commandType; /* INSERT/UPDATE/DELETE/DO NOTHING */ + OverridingKind override; /* OVERRIDING clause */ + Node *qual; /* transformed WHEN conditions */ + List *targetList; /* the target list (of TargetEntry) */ + List *updateColnos; /* target attribute numbers of an UPDATE */ +} MergeAction; + /* * TriggerTransition - * representation of transition row or table naming clause @@ -1737,6 +1776,20 @@ typedef struct UpdateStmt WithClause *withClause; /* WITH clause */ } UpdateStmt; +/* ---------------------- + * Merge Statement + * ---------------------- + */ +typedef struct MergeStmt +{ + NodeTag type; + RangeVar *relation; /* target relation to merge into */ + Node *sourceRelation; /* source relation */ + Node *joinCondition; /* join condition between source and target */ + List *mergeWhenClauses; /* list of MergeWhenClause(es) */ + WithClause *withClause; /* WITH clause */ +} MergeStmt; + /* ---------------------- * Select Statement * diff --git a/src/include/nodes/pathnodes.h b/src/include/nodes/pathnodes.h index 1f3845b3fe..365000bdcd 100644 --- a/src/include/nodes/pathnodes.h +++ b/src/include/nodes/pathnodes.h @@ -1875,7 +1875,7 @@ typedef struct LockRowsPath } LockRowsPath; /* - * ModifyTablePath represents performing INSERT/UPDATE/DELETE modifications + * ModifyTablePath represents performing INSERT/UPDATE/DELETE/MERGE * * We represent most things that will be in the ModifyTable plan node * literally, except we have a child Path not Plan. But analysis of the @@ -1885,7 +1885,7 @@ typedef struct ModifyTablePath { Path path; Path *subpath; /* Path producing source data */ - CmdType operation; /* INSERT, UPDATE, or DELETE */ + CmdType operation; /* INSERT, UPDATE, DELETE, or MERGE */ bool canSetTag; /* do we set the command tag/es_processed? */ Index nominalRelation; /* Parent RT index for use of EXPLAIN */ Index rootRelation; /* Root RT index, if target is partitioned */ @@ -1897,6 +1897,8 @@ typedef struct ModifyTablePath List *rowMarks; /* PlanRowMarks (non-locking only) */ OnConflictExpr *onconflict; /* ON CONFLICT clause, or NULL */ int epqParam; /* ID of Param for EvalPlanQual re-eval */ + List *mergeActionLists; /* per-target-table lists of actions for + * MERGE */ } ModifyTablePath; /* diff --git a/src/include/nodes/plannodes.h b/src/include/nodes/plannodes.h index 0b518ce6b2..50ef3dda05 100644 --- a/src/include/nodes/plannodes.h +++ b/src/include/nodes/plannodes.h @@ -19,6 +19,7 @@ #include "lib/stringinfo.h" #include "nodes/bitmapset.h" #include "nodes/lockoptions.h" +#include "nodes/parsenodes.h" #include "nodes/primnodes.h" @@ -43,7 +44,7 @@ typedef struct PlannedStmt { NodeTag type; - CmdType commandType; /* select|insert|update|delete|utility */ + CmdType commandType; /* select|insert|update|delete|merge|utility */ uint64 queryId; /* query identifier (copied from Query) */ @@ -217,7 +218,7 @@ typedef struct ProjectSet typedef struct ModifyTable { Plan plan; - CmdType operation; /* INSERT, UPDATE, or DELETE */ + CmdType operation; /* INSERT, UPDATE, DELETE, or MERGE */ bool canSetTag; /* do we set the command tag/es_processed? */ Index nominalRelation; /* Parent RT index for use of EXPLAIN */ Index rootRelation; /* Root RT index, if target is partitioned */ @@ -237,6 +238,8 @@ typedef struct ModifyTable Node *onConflictWhere; /* WHERE for ON CONFLICT UPDATE */ Index exclRelRTI; /* RTI of the EXCLUDED pseudo relation */ List *exclRelTlist; /* tlist of the EXCLUDED pseudo relation */ + List *mergeActionLists; /* per-target-table lists of actions for + * MERGE */ } ModifyTable; struct PartitionPruneInfo; /* forward reference to struct below */ diff --git a/src/include/optimizer/pathnode.h b/src/include/optimizer/pathnode.h index 620eeda2d6..6eca547af8 100644 --- a/src/include/optimizer/pathnode.h +++ b/src/include/optimizer/pathnode.h @@ -276,7 +276,7 @@ extern ModifyTablePath *create_modifytable_path(PlannerInfo *root, List *updateColnosLists, List *withCheckOptionLists, List *returningLists, List *rowMarks, OnConflictExpr *onconflict, - int epqParam); + List *mergeActionLists, int epqParam); extern LimitPath *create_limit_path(PlannerInfo *root, RelOptInfo *rel, Path *subpath, Node *limitOffset, Node *limitCount, diff --git a/src/include/optimizer/prep.h b/src/include/optimizer/prep.h index 006b4d02c3..2b11ff1d1f 100644 --- a/src/include/optimizer/prep.h +++ b/src/include/optimizer/prep.h @@ -21,6 +21,7 @@ /* * prototypes for prepjointree.c */ +extern void transform_MERGE_to_join(Query *parse); extern void replace_empty_jointree(Query *parse); extern void pull_up_sublinks(PlannerInfo *root); extern void preprocess_function_rtes(PlannerInfo *root); diff --git a/src/include/parser/analyze.h b/src/include/parser/analyze.h index b30cbd26bf..c69920d108 100644 --- a/src/include/parser/analyze.h +++ b/src/include/parser/analyze.h @@ -39,6 +39,11 @@ extern Query *parse_sub_analyze(Node *parseTree, ParseState *parentParseState, bool locked_from_parent, bool resolve_unknowns); +extern List *transformInsertRow(ParseState *pstate, List *exprlist, + List *stmtcols, List *icolumns, List *attrnos, + bool strip_indirection); +extern List *transformUpdateTargetList(ParseState *pstate, + List *targetList); extern Query *transformTopLevelStmt(ParseState *pstate, RawStmt *parseTree); extern Query *transformStmt(ParseState *pstate, Node *parseTree); diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h index f44440d4a9..10829941e0 100644 --- a/src/include/parser/kwlist.h +++ b/src/include/parser/kwlist.h @@ -259,8 +259,10 @@ PG_KEYWORD("locked", LOCKED, UNRESERVED_KEYWORD, BARE_LABEL) PG_KEYWORD("logged", LOGGED, UNRESERVED_KEYWORD, BARE_LABEL) PG_KEYWORD("mapping", MAPPING, UNRESERVED_KEYWORD, BARE_LABEL) PG_KEYWORD("match", MATCH, UNRESERVED_KEYWORD, BARE_LABEL) +PG_KEYWORD("matched", MATCHED, UNRESERVED_KEYWORD, BARE_LABEL) PG_KEYWORD("materialized", MATERIALIZED, UNRESERVED_KEYWORD, BARE_LABEL) PG_KEYWORD("maxvalue", MAXVALUE, UNRESERVED_KEYWORD, BARE_LABEL) +PG_KEYWORD("merge", MERGE, UNRESERVED_KEYWORD, BARE_LABEL) PG_KEYWORD("method", METHOD, UNRESERVED_KEYWORD, BARE_LABEL) PG_KEYWORD("minute", MINUTE_P, UNRESERVED_KEYWORD, AS_LABEL) PG_KEYWORD("minvalue", MINVALUE, UNRESERVED_KEYWORD, BARE_LABEL) diff --git a/src/include/parser/parse_merge.h b/src/include/parser/parse_merge.h new file mode 100644 index 0000000000..1a1baa1f48 --- /dev/null +++ b/src/include/parser/parse_merge.h @@ -0,0 +1,21 @@ +/*------------------------------------------------------------------------- + * + * parse_merge.h + * handle MERGE statement in parser + * + * + * Portions Copyright (c) 1996-2022, PostgreSQL Global Development Group + * Portions Copyright (c) 1994, Regents of the University of California + * + * src/include/parser/parse_merge.h + * + *------------------------------------------------------------------------- + */ +#ifndef PARSE_MERGE_H +#define PARSE_MERGE_H + +#include "parser/parse_node.h" + +extern Query *transformMergeStmt(ParseState *pstate, MergeStmt *stmt); + +#endif /* PARSE_MERGE_H */ diff --git a/src/include/parser/parse_node.h b/src/include/parser/parse_node.h index 8c859d0d0e..cf9c759025 100644 --- a/src/include/parser/parse_node.h +++ b/src/include/parser/parse_node.h @@ -55,6 +55,7 @@ typedef enum ParseExprKind EXPR_KIND_INSERT_TARGET, /* INSERT target list item */ EXPR_KIND_UPDATE_SOURCE, /* UPDATE assignment source item */ EXPR_KIND_UPDATE_TARGET, /* UPDATE assignment target item */ + EXPR_KIND_MERGE_WHEN, /* MERGE WHEN [NOT] MATCHED condition */ EXPR_KIND_GROUP_BY, /* GROUP BY */ EXPR_KIND_ORDER_BY, /* ORDER BY */ EXPR_KIND_DISTINCT_ON, /* DISTINCT ON */ @@ -135,7 +136,7 @@ typedef Node *(*CoerceParamHook) (ParseState *pstate, Param *param, * p_parent_cte: CommonTableExpr that immediately contains the current query, * if any. * - * p_target_relation: target relation, if query is INSERT, UPDATE, or DELETE. + * p_target_relation: target relation, if query is INSERT/UPDATE/DELETE/MERGE * * p_target_nsitem: target relation's ParseNamespaceItem. * @@ -189,7 +190,7 @@ struct ParseState List *p_ctenamespace; /* current namespace for common table exprs */ List *p_future_ctes; /* common table exprs not yet in namespace */ CommonTableExpr *p_parent_cte; /* this query's containing CTE */ - Relation p_target_relation; /* INSERT/UPDATE/DELETE target rel */ + Relation p_target_relation; /* INSERT/UPDATE/DELETE/MERGE target rel */ ParseNamespaceItem *p_target_nsitem; /* target rel's NSItem, or NULL */ bool p_is_insert; /* process assignment like INSERT not UPDATE */ List *p_windowdefs; /* raw representations of window clauses */ diff --git a/src/include/parser/parse_relation.h b/src/include/parser/parse_relation.h index 06dc27995b..de21c3c649 100644 --- a/src/include/parser/parse_relation.h +++ b/src/include/parser/parse_relation.h @@ -113,7 +113,8 @@ extern List *expandNSItemVars(ParseNamespaceItem *nsitem, int sublevels_up, int location, List **colnames); extern List *expandNSItemAttrs(ParseState *pstate, ParseNamespaceItem *nsitem, - int sublevels_up, int location); + int sublevels_up, bool require_col_privs, + int location); extern int attnameAttNum(Relation rd, const char *attname, bool sysColOK); extern const NameData *attnumAttName(Relation rd, int attid); extern Oid attnumTypeId(Relation rd, int attid); diff --git a/src/include/tcop/cmdtaglist.h b/src/include/tcop/cmdtaglist.h index 4bc7ddf410..2b1163ce33 100644 --- a/src/include/tcop/cmdtaglist.h +++ b/src/include/tcop/cmdtaglist.h @@ -186,6 +186,7 @@ PG_CMDTAG(CMDTAG_INSERT, "INSERT", false, false, true) PG_CMDTAG(CMDTAG_LISTEN, "LISTEN", false, false, false) PG_CMDTAG(CMDTAG_LOAD, "LOAD", false, false, false) PG_CMDTAG(CMDTAG_LOCK_TABLE, "LOCK TABLE", false, false, false) +PG_CMDTAG(CMDTAG_MERGE, "MERGE", false, false, true) PG_CMDTAG(CMDTAG_MOVE, "MOVE", false, false, true) PG_CMDTAG(CMDTAG_NOTIFY, "NOTIFY", false, false, false) PG_CMDTAG(CMDTAG_PREPARE, "PREPARE", false, false, false) diff --git a/src/interfaces/libpq/fe-exec.c b/src/interfaces/libpq/fe-exec.c index 0c39bc9abf..78cff4475c 100644 --- a/src/interfaces/libpq/fe-exec.c +++ b/src/interfaces/libpq/fe-exec.c @@ -3670,9 +3670,9 @@ PQoidValue(const PGresult *res) /* * PQcmdTuples - - * If the last command was INSERT/UPDATE/DELETE/MOVE/FETCH/COPY, return - * a string containing the number of inserted/affected tuples. If not, - * return "". + * If the last command was INSERT/UPDATE/DELETE/MERGE/MOVE/FETCH/COPY, + * return a string containing the number of inserted/affected tuples. + * If not, return "". * * XXX: this should probably return an int */ @@ -3699,7 +3699,8 @@ PQcmdTuples(PGresult *res) strncmp(res->cmdStatus, "DELETE ", 7) == 0 || strncmp(res->cmdStatus, "UPDATE ", 7) == 0) p = res->cmdStatus + 7; - else if (strncmp(res->cmdStatus, "FETCH ", 6) == 0) + else if (strncmp(res->cmdStatus, "FETCH ", 6) == 0 || + strncmp(res->cmdStatus, "MERGE ", 6) == 0) p = res->cmdStatus + 6; else if (strncmp(res->cmdStatus, "MOVE ", 5) == 0 || strncmp(res->cmdStatus, "COPY ", 5) == 0) diff --git a/src/pl/plpgsql/src/pl_exec.c b/src/pl/plpgsql/src/pl_exec.c index 915139378e..00328fddcf 100644 --- a/src/pl/plpgsql/src/pl_exec.c +++ b/src/pl/plpgsql/src/pl_exec.c @@ -4194,7 +4194,7 @@ exec_stmt_execsql(PLpgSQL_execstate *estate, /* * On the first call for this statement generate the plan, and detect - * whether the statement is INSERT/UPDATE/DELETE + * whether the statement is INSERT/UPDATE/DELETE/MERGE */ if (expr->plan == NULL) exec_prepare_plan(estate, expr, CURSOR_OPT_PARALLEL_OK); @@ -4216,7 +4216,8 @@ exec_stmt_execsql(PLpgSQL_execstate *estate, */ if (plansource->commandTag == CMDTAG_INSERT || plansource->commandTag == CMDTAG_UPDATE || - plansource->commandTag == CMDTAG_DELETE) + plansource->commandTag == CMDTAG_DELETE || + plansource->commandTag == CMDTAG_MERGE) { stmt->mod_stmt = true; break; @@ -4276,6 +4277,7 @@ exec_stmt_execsql(PLpgSQL_execstate *estate, case SPI_OK_INSERT_RETURNING: case SPI_OK_UPDATE_RETURNING: case SPI_OK_DELETE_RETURNING: + case SPI_OK_MERGE: Assert(stmt->mod_stmt); exec_set_found(estate, (SPI_processed != 0)); break; @@ -4457,6 +4459,7 @@ exec_stmt_dynexecute(PLpgSQL_execstate *estate, case SPI_OK_INSERT_RETURNING: case SPI_OK_UPDATE_RETURNING: case SPI_OK_DELETE_RETURNING: + case SPI_OK_MERGE: case SPI_OK_UTILITY: case SPI_OK_REWRITTEN: break; diff --git a/src/pl/plpgsql/src/pl_gram.y b/src/pl/plpgsql/src/pl_gram.y index 954c2df331..11e86c1609 100644 --- a/src/pl/plpgsql/src/pl_gram.y +++ b/src/pl/plpgsql/src/pl_gram.y @@ -306,6 +306,7 @@ static void check_raise_parameters(PLpgSQL_stmt_raise *stmt); %token K_LAST %token K_LOG %token K_LOOP +%token K_MERGE %token K_MESSAGE %token K_MESSAGE_TEXT %token K_MOVE @@ -2000,6 +2001,10 @@ stmt_execsql : K_IMPORT { $$ = make_execsql_stmt(K_INSERT, @1); } + | K_MERGE + { + $$ = make_execsql_stmt(K_MERGE, @1); + } | T_WORD { int tok; @@ -2537,6 +2542,7 @@ unreserved_keyword : | K_IS | K_LAST | K_LOG + | K_MERGE | K_MESSAGE | K_MESSAGE_TEXT | K_MOVE @@ -3000,6 +3006,8 @@ make_execsql_stmt(int firsttoken, int location) { if (prev_tok == K_INSERT) continue; /* INSERT INTO is not an INTO-target */ + if (prev_tok == K_MERGE) + continue; /* MERGE INTO is not an INTO-target */ if (firsttoken == K_IMPORT) continue; /* IMPORT ... INTO is not an INTO-target */ if (have_into) diff --git a/src/pl/plpgsql/src/pl_unreserved_kwlist.h b/src/pl/plpgsql/src/pl_unreserved_kwlist.h index 1c68420331..ee2be1b212 100644 --- a/src/pl/plpgsql/src/pl_unreserved_kwlist.h +++ b/src/pl/plpgsql/src/pl_unreserved_kwlist.h @@ -70,6 +70,7 @@ PG_KEYWORD("insert", K_INSERT) PG_KEYWORD("is", K_IS) PG_KEYWORD("last", K_LAST) PG_KEYWORD("log", K_LOG) +PG_KEYWORD("merge", K_MERGE) PG_KEYWORD("message", K_MESSAGE) PG_KEYWORD("message_text", K_MESSAGE_TEXT) PG_KEYWORD("move", K_MOVE) diff --git a/src/pl/plpgsql/src/plpgsql.h b/src/pl/plpgsql/src/plpgsql.h index 18a4f6c7d3..813c32c70f 100644 --- a/src/pl/plpgsql/src/plpgsql.h +++ b/src/pl/plpgsql/src/plpgsql.h @@ -893,7 +893,7 @@ typedef struct PLpgSQL_stmt_execsql int lineno; unsigned int stmtid; PLpgSQL_expr *sqlstmt; - bool mod_stmt; /* is the stmt INSERT/UPDATE/DELETE? */ + bool mod_stmt; /* is the stmt INSERT/UPDATE/DELETE/MERGE? */ bool mod_stmt_set; /* is mod_stmt valid yet? */ bool into; /* INTO supplied? */ bool strict; /* INTO STRICT flag */ diff --git a/src/test/isolation/expected/merge-delete.out b/src/test/isolation/expected/merge-delete.out new file mode 100644 index 0000000000..b2befa8e16 --- /dev/null +++ b/src/test/isolation/expected/merge-delete.out @@ -0,0 +1,117 @@ +Parsed test spec with 2 sessions + +starting permutation: delete c1 select2 c2 +step delete: DELETE FROM target t WHERE t.key = 1; +step c1: COMMIT; +step select2: SELECT * FROM target; +key|val +---+--- +(0 rows) + +step c2: COMMIT; + +starting permutation: merge_delete c1 select2 c2 +step merge_delete: MERGE INTO target t USING (SELECT 1 as key) s ON s.key = t.key WHEN MATCHED THEN DELETE; +step c1: COMMIT; +step select2: SELECT * FROM target; +key|val +---+--- +(0 rows) + +step c2: COMMIT; + +starting permutation: delete c1 update1 select2 c2 +step delete: DELETE FROM target t WHERE t.key = 1; +step c1: COMMIT; +step update1: UPDATE target t SET val = t.val || ' updated by update1' WHERE t.key = 1; +step select2: SELECT * FROM target; +key|val +---+--- +(0 rows) + +step c2: COMMIT; + +starting permutation: merge_delete c1 update1 select2 c2 +step merge_delete: MERGE INTO target t USING (SELECT 1 as key) s ON s.key = t.key WHEN MATCHED THEN DELETE; +step c1: COMMIT; +step update1: UPDATE target t SET val = t.val || ' updated by update1' WHERE t.key = 1; +step select2: SELECT * FROM target; +key|val +---+--- +(0 rows) + +step c2: COMMIT; + +starting permutation: delete c1 merge2 select2 c2 +step delete: DELETE FROM target t WHERE t.key = 1; +step c1: COMMIT; +step merge2: MERGE INTO target t USING (SELECT 1 as key, 'merge2a' as val) s ON s.key = t.key WHEN NOT MATCHED THEN INSERT VALUES (s.key, s.val) WHEN MATCHED THEN UPDATE set key = t.key + 1, val = t.val || ' updated by ' || s.val; +step select2: SELECT * FROM target; +key|val +---+------- + 1|merge2a +(1 row) + +step c2: COMMIT; + +starting permutation: merge_delete c1 merge2 select2 c2 +step merge_delete: MERGE INTO target t USING (SELECT 1 as key) s ON s.key = t.key WHEN MATCHED THEN DELETE; +step c1: COMMIT; +step merge2: MERGE INTO target t USING (SELECT 1 as key, 'merge2a' as val) s ON s.key = t.key WHEN NOT MATCHED THEN INSERT VALUES (s.key, s.val) WHEN MATCHED THEN UPDATE set key = t.key + 1, val = t.val || ' updated by ' || s.val; +step select2: SELECT * FROM target; +key|val +---+------- + 1|merge2a +(1 row) + +step c2: COMMIT; + +starting permutation: delete update1 c1 select2 c2 +step delete: DELETE FROM target t WHERE t.key = 1; +step update1: UPDATE target t SET val = t.val || ' updated by update1' WHERE t.key = 1; +step c1: COMMIT; +step update1: <... completed> +step select2: SELECT * FROM target; +key|val +---+--- +(0 rows) + +step c2: COMMIT; + +starting permutation: merge_delete update1 c1 select2 c2 +step merge_delete: MERGE INTO target t USING (SELECT 1 as key) s ON s.key = t.key WHEN MATCHED THEN DELETE; +step update1: UPDATE target t SET val = t.val || ' updated by update1' WHERE t.key = 1; +step c1: COMMIT; +step update1: <... completed> +step select2: SELECT * FROM target; +key|val +---+--- +(0 rows) + +step c2: COMMIT; + +starting permutation: delete merge2 c1 select2 c2 +step delete: DELETE FROM target t WHERE t.key = 1; +step merge2: MERGE INTO target t USING (SELECT 1 as key, 'merge2a' as val) s ON s.key = t.key WHEN NOT MATCHED THEN INSERT VALUES (s.key, s.val) WHEN MATCHED THEN UPDATE set key = t.key + 1, val = t.val || ' updated by ' || s.val; +step c1: COMMIT; +step merge2: <... completed> +step select2: SELECT * FROM target; +key|val +---+------- + 1|merge2a +(1 row) + +step c2: COMMIT; + +starting permutation: merge_delete merge2 c1 select2 c2 +step merge_delete: MERGE INTO target t USING (SELECT 1 as key) s ON s.key = t.key WHEN MATCHED THEN DELETE; +step merge2: MERGE INTO target t USING (SELECT 1 as key, 'merge2a' as val) s ON s.key = t.key WHEN NOT MATCHED THEN INSERT VALUES (s.key, s.val) WHEN MATCHED THEN UPDATE set key = t.key + 1, val = t.val || ' updated by ' || s.val; +step c1: COMMIT; +step merge2: <... completed> +step select2: SELECT * FROM target; +key|val +---+------- + 1|merge2a +(1 row) + +step c2: COMMIT; diff --git a/src/test/isolation/expected/merge-insert-update.out b/src/test/isolation/expected/merge-insert-update.out new file mode 100644 index 0000000000..ee8b3c4e9f --- /dev/null +++ b/src/test/isolation/expected/merge-insert-update.out @@ -0,0 +1,94 @@ +Parsed test spec with 2 sessions + +starting permutation: merge1 c1 select2 c2 +step merge1: MERGE INTO target t USING (SELECT 1 as key, 'merge1' as val) s ON s.key = t.key WHEN NOT MATCHED THEN INSERT VALUES (s.key, s.val) WHEN MATCHED THEN UPDATE set val = t.val || ' updated by merge1'; +step c1: COMMIT; +step select2: SELECT * FROM target; +key|val +---+------ + 1|merge1 +(1 row) + +step c2: COMMIT; + +starting permutation: merge1 c1 merge2 select2 c2 +step merge1: MERGE INTO target t USING (SELECT 1 as key, 'merge1' as val) s ON s.key = t.key WHEN NOT MATCHED THEN INSERT VALUES (s.key, s.val) WHEN MATCHED THEN UPDATE set val = t.val || ' updated by merge1'; +step c1: COMMIT; +step merge2: MERGE INTO target t USING (SELECT 1 as key, 'merge2' as val) s ON s.key = t.key WHEN NOT MATCHED THEN INSERT VALUES (s.key, s.val) WHEN MATCHED THEN UPDATE set val = t.val || ' updated by merge2'; +step select2: SELECT * FROM target; +key|val +---+------------------------ + 1|merge1 updated by merge2 +(1 row) + +step c2: COMMIT; + +starting permutation: insert1 merge2 c1 select2 c2 +step insert1: INSERT INTO target VALUES (1, 'insert1'); +step merge2: MERGE INTO target t USING (SELECT 1 as key, 'merge2' as val) s ON s.key = t.key WHEN NOT MATCHED THEN INSERT VALUES (s.key, s.val) WHEN MATCHED THEN UPDATE set val = t.val || ' updated by merge2'; +step c1: COMMIT; +step merge2: <... completed> +ERROR: duplicate key value violates unique constraint "target_pkey" +step select2: SELECT * FROM target; +ERROR: current transaction is aborted, commands ignored until end of transaction block +step c2: COMMIT; + +starting permutation: merge1 merge2 c1 select2 c2 +step merge1: MERGE INTO target t USING (SELECT 1 as key, 'merge1' as val) s ON s.key = t.key WHEN NOT MATCHED THEN INSERT VALUES (s.key, s.val) WHEN MATCHED THEN UPDATE set val = t.val || ' updated by merge1'; +step merge2: MERGE INTO target t USING (SELECT 1 as key, 'merge2' as val) s ON s.key = t.key WHEN NOT MATCHED THEN INSERT VALUES (s.key, s.val) WHEN MATCHED THEN UPDATE set val = t.val || ' updated by merge2'; +step c1: COMMIT; +step merge2: <... completed> +ERROR: duplicate key value violates unique constraint "target_pkey" +step select2: SELECT * FROM target; +ERROR: current transaction is aborted, commands ignored until end of transaction block +step c2: COMMIT; + +starting permutation: merge1 merge2 a1 select2 c2 +step merge1: MERGE INTO target t USING (SELECT 1 as key, 'merge1' as val) s ON s.key = t.key WHEN NOT MATCHED THEN INSERT VALUES (s.key, s.val) WHEN MATCHED THEN UPDATE set val = t.val || ' updated by merge1'; +step merge2: MERGE INTO target t USING (SELECT 1 as key, 'merge2' as val) s ON s.key = t.key WHEN NOT MATCHED THEN INSERT VALUES (s.key, s.val) WHEN MATCHED THEN UPDATE set val = t.val || ' updated by merge2'; +step a1: ABORT; +step merge2: <... completed> +step select2: SELECT * FROM target; +key|val +---+------ + 1|merge2 +(1 row) + +step c2: COMMIT; + +starting permutation: delete1 insert1 c1 merge2 select2 c2 +step delete1: DELETE FROM target WHERE key = 1; +step insert1: INSERT INTO target VALUES (1, 'insert1'); +step c1: COMMIT; +step merge2: MERGE INTO target t USING (SELECT 1 as key, 'merge2' as val) s ON s.key = t.key WHEN NOT MATCHED THEN INSERT VALUES (s.key, s.val) WHEN MATCHED THEN UPDATE set val = t.val || ' updated by merge2'; +step select2: SELECT * FROM target; +key|val +---+------------------------- + 1|insert1 updated by merge2 +(1 row) + +step c2: COMMIT; + +starting permutation: delete1 insert1 merge2 c1 select2 c2 +step delete1: DELETE FROM target WHERE key = 1; +step insert1: INSERT INTO target VALUES (1, 'insert1'); +step merge2: MERGE INTO target t USING (SELECT 1 as key, 'merge2' as val) s ON s.key = t.key WHEN NOT MATCHED THEN INSERT VALUES (s.key, s.val) WHEN MATCHED THEN UPDATE set val = t.val || ' updated by merge2'; +step c1: COMMIT; +step merge2: <... completed> +ERROR: duplicate key value violates unique constraint "target_pkey" +step select2: SELECT * FROM target; +ERROR: current transaction is aborted, commands ignored until end of transaction block +step c2: COMMIT; + +starting permutation: delete1 insert1 merge2i c1 select2 c2 +step delete1: DELETE FROM target WHERE key = 1; +step insert1: INSERT INTO target VALUES (1, 'insert1'); +step merge2i: MERGE INTO target t USING (SELECT 1 as key, 'merge2' as val) s ON s.key = t.key WHEN MATCHED THEN UPDATE set val = t.val || ' updated by merge2'; +step c1: COMMIT; +step select2: SELECT * FROM target; +key|val +---+------- + 1|insert1 +(1 row) + +step c2: COMMIT; diff --git a/src/test/isolation/expected/merge-match-recheck.out b/src/test/isolation/expected/merge-match-recheck.out new file mode 100644 index 0000000000..8183f52ce0 --- /dev/null +++ b/src/test/isolation/expected/merge-match-recheck.out @@ -0,0 +1,116 @@ +Parsed test spec with 2 sessions + +starting permutation: update1 merge_status c2 select1 c1 +step update1: UPDATE target t SET balance = balance + 10, val = t.val || ' updated by update1' WHERE t.key = 1; +step merge_status: + MERGE INTO target t + USING (SELECT 1 as key) s + ON s.key = t.key + WHEN MATCHED AND status = 's1' THEN + UPDATE SET status = 's2', val = t.val || ' when1' + WHEN MATCHED AND status = 's2' THEN + UPDATE SET status = 's3', val = t.val || ' when2' + WHEN MATCHED AND status = 's3' THEN + UPDATE SET status = 's4', val = t.val || ' when3'; + +step c2: COMMIT; +step merge_status: <... completed> +step select1: SELECT * FROM target; +key|balance|status|val +---+-------+------+------------------------------ + 1| 170|s2 |setup updated by update1 when1 +(1 row) + +step c1: COMMIT; + +starting permutation: update2 merge_status c2 select1 c1 +step update2: UPDATE target t SET status = 's2', val = t.val || ' updated by update2' WHERE t.key = 1; +step merge_status: + MERGE INTO target t + USING (SELECT 1 as key) s + ON s.key = t.key + WHEN MATCHED AND status = 's1' THEN + UPDATE SET status = 's2', val = t.val || ' when1' + WHEN MATCHED AND status = 's2' THEN + UPDATE SET status = 's3', val = t.val || ' when2' + WHEN MATCHED AND status = 's3' THEN + UPDATE SET status = 's4', val = t.val || ' when3'; + +step c2: COMMIT; +step merge_status: <... completed> +step select1: SELECT * FROM target; +key|balance|status|val +---+-------+------+------------------------------ + 1| 160|s3 |setup updated by update2 when2 +(1 row) + +step c1: COMMIT; + +starting permutation: update3 merge_status c2 select1 c1 +step update3: UPDATE target t SET status = 's3', val = t.val || ' updated by update3' WHERE t.key = 1; +step merge_status: + MERGE INTO target t + USING (SELECT 1 as key) s + ON s.key = t.key + WHEN MATCHED AND status = 's1' THEN + UPDATE SET status = 's2', val = t.val || ' when1' + WHEN MATCHED AND status = 's2' THEN + UPDATE SET status = 's3', val = t.val || ' when2' + WHEN MATCHED AND status = 's3' THEN + UPDATE SET status = 's4', val = t.val || ' when3'; + +step c2: COMMIT; +step merge_status: <... completed> +step select1: SELECT * FROM target; +key|balance|status|val +---+-------+------+------------------------------ + 1| 160|s4 |setup updated by update3 when3 +(1 row) + +step c1: COMMIT; + +starting permutation: update5 merge_status c2 select1 c1 +step update5: UPDATE target t SET status = 's5', val = t.val || ' updated by update5' WHERE t.key = 1; +step merge_status: + MERGE INTO target t + USING (SELECT 1 as key) s + ON s.key = t.key + WHEN MATCHED AND status = 's1' THEN + UPDATE SET status = 's2', val = t.val || ' when1' + WHEN MATCHED AND status = 's2' THEN + UPDATE SET status = 's3', val = t.val || ' when2' + WHEN MATCHED AND status = 's3' THEN + UPDATE SET status = 's4', val = t.val || ' when3'; + +step c2: COMMIT; +step merge_status: <... completed> +step select1: SELECT * FROM target; +key|balance|status|val +---+-------+------+------------------------ + 1| 160|s5 |setup updated by update5 +(1 row) + +step c1: COMMIT; + +starting permutation: update_bal1 merge_bal c2 select1 c1 +step update_bal1: UPDATE target t SET balance = 50, val = t.val || ' updated by update_bal1' WHERE t.key = 1; +step merge_bal: + MERGE INTO target t + USING (SELECT 1 as key) s + ON s.key = t.key + WHEN MATCHED AND balance < 100 THEN + UPDATE SET balance = balance * 2, val = t.val || ' when1' + WHEN MATCHED AND balance < 200 THEN + UPDATE SET balance = balance * 4, val = t.val || ' when2' + WHEN MATCHED AND balance < 300 THEN + UPDATE SET balance = balance * 8, val = t.val || ' when3'; + +step c2: COMMIT; +step merge_bal: <... completed> +step select1: SELECT * FROM target; +key|balance|status|val +---+-------+------+---------------------------------- + 1| 100|s1 |setup updated by update_bal1 when1 +(1 row) + +step c1: COMMIT; diff --git a/src/test/isolation/expected/merge-update.out b/src/test/isolation/expected/merge-update.out new file mode 100644 index 0000000000..55b1f908fd --- /dev/null +++ b/src/test/isolation/expected/merge-update.out @@ -0,0 +1,314 @@ +Parsed test spec with 2 sessions + +starting permutation: merge1 c1 select2 c2 +step merge1: + MERGE INTO target t + USING (SELECT 1 as key, 'merge1' as val) s + ON s.key = t.key + WHEN NOT MATCHED THEN + INSERT VALUES (s.key, s.val) + WHEN MATCHED THEN + UPDATE set key = t.key + 1, val = t.val || ' updated by ' || s.val; + +step c1: COMMIT; +step select2: SELECT * FROM target; +key|val +---+------------------------ + 2|setup1 updated by merge1 +(1 row) + +step c2: COMMIT; + +starting permutation: merge1 c1 merge2a select2 c2 +step merge1: + MERGE INTO target t + USING (SELECT 1 as key, 'merge1' as val) s + ON s.key = t.key + WHEN NOT MATCHED THEN + INSERT VALUES (s.key, s.val) + WHEN MATCHED THEN + UPDATE set key = t.key + 1, val = t.val || ' updated by ' || s.val; + +step c1: COMMIT; +step merge2a: + MERGE INTO target t + USING (SELECT 1 as key, 'merge2a' as val) s + ON s.key = t.key + WHEN NOT MATCHED THEN + INSERT VALUES (s.key, s.val) + WHEN MATCHED THEN + UPDATE set key = t.key + 1, val = t.val || ' updated by ' || s.val; + +step select2: SELECT * FROM target; +key|val +---+------------------------ + 2|setup1 updated by merge1 + 1|merge2a +(2 rows) + +step c2: COMMIT; + +starting permutation: merge1 merge2a c1 select2 c2 +step merge1: + MERGE INTO target t + USING (SELECT 1 as key, 'merge1' as val) s + ON s.key = t.key + WHEN NOT MATCHED THEN + INSERT VALUES (s.key, s.val) + WHEN MATCHED THEN + UPDATE set key = t.key + 1, val = t.val || ' updated by ' || s.val; + +step merge2a: + MERGE INTO target t + USING (SELECT 1 as key, 'merge2a' as val) s + ON s.key = t.key + WHEN NOT MATCHED THEN + INSERT VALUES (s.key, s.val) + WHEN MATCHED THEN + UPDATE set key = t.key + 1, val = t.val || ' updated by ' || s.val; + +step c1: COMMIT; +step merge2a: <... completed> +step select2: SELECT * FROM target; +key|val +---+------------------------ + 2|setup1 updated by merge1 + 1|merge2a +(2 rows) + +step c2: COMMIT; + +starting permutation: merge1 merge2a a1 select2 c2 +step merge1: + MERGE INTO target t + USING (SELECT 1 as key, 'merge1' as val) s + ON s.key = t.key + WHEN NOT MATCHED THEN + INSERT VALUES (s.key, s.val) + WHEN MATCHED THEN + UPDATE set key = t.key + 1, val = t.val || ' updated by ' || s.val; + +step merge2a: + MERGE INTO target t + USING (SELECT 1 as key, 'merge2a' as val) s + ON s.key = t.key + WHEN NOT MATCHED THEN + INSERT VALUES (s.key, s.val) + WHEN MATCHED THEN + UPDATE set key = t.key + 1, val = t.val || ' updated by ' || s.val; + +step a1: ABORT; +step merge2a: <... completed> +step select2: SELECT * FROM target; +key|val +---+------------------------- + 2|setup1 updated by merge2a +(1 row) + +step c2: COMMIT; + +starting permutation: merge1 merge2b c1 select2 c2 +step merge1: + MERGE INTO target t + USING (SELECT 1 as key, 'merge1' as val) s + ON s.key = t.key + WHEN NOT MATCHED THEN + INSERT VALUES (s.key, s.val) + WHEN MATCHED THEN + UPDATE set key = t.key + 1, val = t.val || ' updated by ' || s.val; + +step merge2b: + MERGE INTO target t + USING (SELECT 1 as key, 'merge2b' as val) s + ON s.key = t.key + WHEN NOT MATCHED THEN + INSERT VALUES (s.key, s.val) + WHEN MATCHED AND t.key < 2 THEN + UPDATE set key = t.key + 1, val = t.val || ' updated by ' || s.val; + +step c1: COMMIT; +step merge2b: <... completed> +step select2: SELECT * FROM target; +key|val +---+------------------------ + 2|setup1 updated by merge1 + 1|merge2b +(2 rows) + +step c2: COMMIT; + +starting permutation: merge1 merge2c c1 select2 c2 +step merge1: + MERGE INTO target t + USING (SELECT 1 as key, 'merge1' as val) s + ON s.key = t.key + WHEN NOT MATCHED THEN + INSERT VALUES (s.key, s.val) + WHEN MATCHED THEN + UPDATE set key = t.key + 1, val = t.val || ' updated by ' || s.val; + +step merge2c: + MERGE INTO target t + USING (SELECT 1 as key, 'merge2c' as val) s + ON s.key = t.key AND t.key < 2 + WHEN NOT MATCHED THEN + INSERT VALUES (s.key, s.val) + WHEN MATCHED THEN + UPDATE set key = t.key + 1, val = t.val || ' updated by ' || s.val; + +step c1: COMMIT; +step merge2c: <... completed> +step select2: SELECT * FROM target; +key|val +---+------------------------ + 2|setup1 updated by merge1 + 1|merge2c +(2 rows) + +step c2: COMMIT; + +starting permutation: pa_merge1 pa_merge2a c1 pa_select2 c2 +step pa_merge1: + MERGE INTO pa_target t + USING (SELECT 1 as key, 'pa_merge1' as val) s + ON s.key = t.key + WHEN NOT MATCHED THEN + INSERT VALUES (s.key, s.val) + WHEN MATCHED THEN + UPDATE set val = t.val || ' updated by ' || s.val; + +step pa_merge2a: + MERGE INTO pa_target t + USING (SELECT 1 as key, 'pa_merge2a' as val) s + ON s.key = t.key + WHEN NOT MATCHED THEN + INSERT VALUES (s.key, s.val) + WHEN MATCHED THEN + UPDATE set key = t.key + 1, val = t.val || ' updated by ' || s.val; + +step c1: COMMIT; +step pa_merge2a: <... completed> +step pa_select2: SELECT * FROM pa_target; +key|val +---+-------------------------------------------------- + 2|initial + 2|initial updated by pa_merge1 updated by pa_merge2a +(2 rows) + +step c2: COMMIT; + +starting permutation: pa_merge2 pa_merge2a c1 pa_select2 c2 +step pa_merge2: + MERGE INTO pa_target t + USING (SELECT 1 as key, 'pa_merge2' as val) s + ON s.key = t.key + WHEN NOT MATCHED THEN + INSERT VALUES (s.key, s.val) + WHEN MATCHED THEN + UPDATE set key = t.key + 1, val = t.val || ' updated by ' || s.val; + +step pa_merge2a: + MERGE INTO pa_target t + USING (SELECT 1 as key, 'pa_merge2a' as val) s + ON s.key = t.key + WHEN NOT MATCHED THEN + INSERT VALUES (s.key, s.val) + WHEN MATCHED THEN + UPDATE set key = t.key + 1, val = t.val || ' updated by ' || s.val; + +step c1: COMMIT; +step pa_merge2a: <... completed> +ERROR: tuple to be locked was already moved to another partition due to concurrent update +step pa_select2: SELECT * FROM pa_target; +ERROR: current transaction is aborted, commands ignored until end of transaction block +step c2: COMMIT; + +starting permutation: pa_merge2 c1 pa_merge2a pa_select2 c2 +step pa_merge2: + MERGE INTO pa_target t + USING (SELECT 1 as key, 'pa_merge2' as val) s + ON s.key = t.key + WHEN NOT MATCHED THEN + INSERT VALUES (s.key, s.val) + WHEN MATCHED THEN + UPDATE set key = t.key + 1, val = t.val || ' updated by ' || s.val; + +step c1: COMMIT; +step pa_merge2a: + MERGE INTO pa_target t + USING (SELECT 1 as key, 'pa_merge2a' as val) s + ON s.key = t.key + WHEN NOT MATCHED THEN + INSERT VALUES (s.key, s.val) + WHEN MATCHED THEN + UPDATE set key = t.key + 1, val = t.val || ' updated by ' || s.val; + +step pa_select2: SELECT * FROM pa_target; +key|val +---+---------------------------- + 1|pa_merge2a + 2|initial + 2|initial updated by pa_merge2 +(3 rows) + +step c2: COMMIT; + +starting permutation: pa_merge3 pa_merge2b_when c1 pa_select2 c2 +step pa_merge3: + MERGE INTO pa_target t + USING (SELECT 1 as key, 'pa_merge2' as val) s + ON s.key = t.key + WHEN NOT MATCHED THEN + INSERT VALUES (s.key, s.val) + WHEN MATCHED THEN + UPDATE set val = 'prefix ' || t.val; + +step pa_merge2b_when: + MERGE INTO pa_target t + USING (SELECT 1 as key, 'pa_merge2b_when' as val) s + ON s.key = t.key + WHEN NOT MATCHED THEN + INSERT VALUES (s.key, s.val) + WHEN MATCHED AND t.val like 'initial%' THEN + UPDATE set key = t.key + 1, val = t.val || ' updated by ' || s.val; + +step c1: COMMIT; +step pa_merge2b_when: <... completed> +step pa_select2: SELECT * FROM pa_target; +key|val +---+-------------- + 1|prefix initial + 2|initial +(2 rows) + +step c2: COMMIT; + +starting permutation: pa_merge1 pa_merge2b_when c1 pa_select2 c2 +step pa_merge1: + MERGE INTO pa_target t + USING (SELECT 1 as key, 'pa_merge1' as val) s + ON s.key = t.key + WHEN NOT MATCHED THEN + INSERT VALUES (s.key, s.val) + WHEN MATCHED THEN + UPDATE set val = t.val || ' updated by ' || s.val; + +step pa_merge2b_when: + MERGE INTO pa_target t + USING (SELECT 1 as key, 'pa_merge2b_when' as val) s + ON s.key = t.key + WHEN NOT MATCHED THEN + INSERT VALUES (s.key, s.val) + WHEN MATCHED AND t.val like 'initial%' THEN + UPDATE set key = t.key + 1, val = t.val || ' updated by ' || s.val; + +step c1: COMMIT; +step pa_merge2b_when: <... completed> +step pa_select2: SELECT * FROM pa_target; +key|val +---+------------------------------------------------------- + 2|initial + 2|initial updated by pa_merge1 updated by pa_merge2b_when +(2 rows) + +step c2: COMMIT; diff --git a/src/test/isolation/isolation_schedule b/src/test/isolation/isolation_schedule index 8e87098150..00749a40bd 100644 --- a/src/test/isolation/isolation_schedule +++ b/src/test/isolation/isolation_schedule @@ -45,6 +45,10 @@ test: insert-conflict-do-update test: insert-conflict-do-update-2 test: insert-conflict-do-update-3 test: insert-conflict-specconflict +test: merge-insert-update +test: merge-delete +test: merge-update +test: merge-match-recheck test: delete-abort-savept test: delete-abort-savept-2 test: aborted-keyrevoke diff --git a/src/test/isolation/specs/merge-delete.spec b/src/test/isolation/specs/merge-delete.spec new file mode 100644 index 0000000000..0e7053270e --- /dev/null +++ b/src/test/isolation/specs/merge-delete.spec @@ -0,0 +1,50 @@ +# MERGE DELETE +# +# This test looks at the interactions involving concurrent deletes +# comparing the behavior of MERGE, DELETE and UPDATE + +setup +{ + CREATE TABLE target (key int primary key, val text); + INSERT INTO target VALUES (1, 'setup1'); +} + +teardown +{ + DROP TABLE target; +} + +session "s1" +setup +{ + BEGIN ISOLATION LEVEL READ COMMITTED; +} +step "delete" { DELETE FROM target t WHERE t.key = 1; } +step "merge_delete" { MERGE INTO target t USING (SELECT 1 as key) s ON s.key = t.key WHEN MATCHED THEN DELETE; } +step "c1" { COMMIT; } + +session "s2" +setup +{ + BEGIN ISOLATION LEVEL READ COMMITTED; +} +step "update1" { UPDATE target t SET val = t.val || ' updated by update1' WHERE t.key = 1; } +step "merge2" { MERGE INTO target t USING (SELECT 1 as key, 'merge2a' as val) s ON s.key = t.key WHEN NOT MATCHED THEN INSERT VALUES (s.key, s.val) WHEN MATCHED THEN UPDATE set key = t.key + 1, val = t.val || ' updated by ' || s.val; } +step "select2" { SELECT * FROM target; } +step "c2" { COMMIT; } + +# Basic effects +permutation "delete" "c1" "select2" "c2" +permutation "merge_delete" "c1" "select2" "c2" + +# One after the other, no concurrency +permutation "delete" "c1" "update1" "select2" "c2" +permutation "merge_delete" "c1" "update1" "select2" "c2" +permutation "delete" "c1" "merge2" "select2" "c2" +permutation "merge_delete" "c1" "merge2" "select2" "c2" + +# Now with concurrency +permutation "delete" "update1" "c1" "select2" "c2" +permutation "merge_delete" "update1" "c1" "select2" "c2" +permutation "delete" "merge2" "c1" "select2" "c2" +permutation "merge_delete" "merge2" "c1" "select2" "c2" diff --git a/src/test/isolation/specs/merge-insert-update.spec b/src/test/isolation/specs/merge-insert-update.spec new file mode 100644 index 0000000000..1bf1ed461d --- /dev/null +++ b/src/test/isolation/specs/merge-insert-update.spec @@ -0,0 +1,51 @@ +# MERGE INSERT UPDATE +# +# This looks at how we handle concurrent INSERTs, illustrating how the +# behavior differs from INSERT ... ON CONFLICT + +setup +{ + CREATE TABLE target (key int primary key, val text); +} + +teardown +{ + DROP TABLE target; +} + +session "s1" +setup +{ + BEGIN ISOLATION LEVEL READ COMMITTED; +} +step "merge1" { MERGE INTO target t USING (SELECT 1 as key, 'merge1' as val) s ON s.key = t.key WHEN NOT MATCHED THEN INSERT VALUES (s.key, s.val) WHEN MATCHED THEN UPDATE set val = t.val || ' updated by merge1'; } +step "delete1" { DELETE FROM target WHERE key = 1; } +step "insert1" { INSERT INTO target VALUES (1, 'insert1'); } +step "c1" { COMMIT; } +step "a1" { ABORT; } + +session "s2" +setup +{ + BEGIN ISOLATION LEVEL READ COMMITTED; +} +step "merge2" { MERGE INTO target t USING (SELECT 1 as key, 'merge2' as val) s ON s.key = t.key WHEN NOT MATCHED THEN INSERT VALUES (s.key, s.val) WHEN MATCHED THEN UPDATE set val = t.val || ' updated by merge2'; } + +step "merge2i" { MERGE INTO target t USING (SELECT 1 as key, 'merge2' as val) s ON s.key = t.key WHEN MATCHED THEN UPDATE set val = t.val || ' updated by merge2'; } + +step "select2" { SELECT * FROM target; } +step "c2" { COMMIT; } + +# Basic effects +permutation "merge1" "c1" "select2" "c2" +permutation "merge1" "c1" "merge2" "select2" "c2" + +# check concurrent inserts +permutation "insert1" "merge2" "c1" "select2" "c2" +permutation "merge1" "merge2" "c1" "select2" "c2" +permutation "merge1" "merge2" "a1" "select2" "c2" + +# check how we handle when visible row has been concurrently deleted, then same key re-inserted +permutation "delete1" "insert1" "c1" "merge2" "select2" "c2" +permutation "delete1" "insert1" "merge2" "c1" "select2" "c2" +permutation "delete1" "insert1" "merge2i" "c1" "select2" "c2" diff --git a/src/test/isolation/specs/merge-match-recheck.spec b/src/test/isolation/specs/merge-match-recheck.spec new file mode 100644 index 0000000000..d56400a6a2 --- /dev/null +++ b/src/test/isolation/specs/merge-match-recheck.spec @@ -0,0 +1,77 @@ +# MERGE MATCHED RECHECK +# +# This test looks at what happens when we have complex +# WHEN MATCHED AND conditions and a concurrent UPDATE causes a +# recheck of the AND condition on the new row + +setup +{ + CREATE TABLE target (key int primary key, balance integer, status text, val text); + INSERT INTO target VALUES (1, 160, 's1', 'setup'); +} + +teardown +{ + DROP TABLE target; +} + +session "s1" +setup +{ + BEGIN ISOLATION LEVEL READ COMMITTED; +} +step "merge_status" +{ + MERGE INTO target t + USING (SELECT 1 as key) s + ON s.key = t.key + WHEN MATCHED AND status = 's1' THEN + UPDATE SET status = 's2', val = t.val || ' when1' + WHEN MATCHED AND status = 's2' THEN + UPDATE SET status = 's3', val = t.val || ' when2' + WHEN MATCHED AND status = 's3' THEN + UPDATE SET status = 's4', val = t.val || ' when3'; +} + +step "merge_bal" +{ + MERGE INTO target t + USING (SELECT 1 as key) s + ON s.key = t.key + WHEN MATCHED AND balance < 100 THEN + UPDATE SET balance = balance * 2, val = t.val || ' when1' + WHEN MATCHED AND balance < 200 THEN + UPDATE SET balance = balance * 4, val = t.val || ' when2' + WHEN MATCHED AND balance < 300 THEN + UPDATE SET balance = balance * 8, val = t.val || ' when3'; +} + +step "select1" { SELECT * FROM target; } +step "c1" { COMMIT; } + +session "s2" +setup +{ + BEGIN ISOLATION LEVEL READ COMMITTED; +} +step "update1" { UPDATE target t SET balance = balance + 10, val = t.val || ' updated by update1' WHERE t.key = 1; } +step "update2" { UPDATE target t SET status = 's2', val = t.val || ' updated by update2' WHERE t.key = 1; } +step "update3" { UPDATE target t SET status = 's3', val = t.val || ' updated by update3' WHERE t.key = 1; } +step "update5" { UPDATE target t SET status = 's5', val = t.val || ' updated by update5' WHERE t.key = 1; } +step "update_bal1" { UPDATE target t SET balance = 50, val = t.val || ' updated by update_bal1' WHERE t.key = 1; } +step "c2" { COMMIT; } + +# merge_status sees concurrently updated row and rechecks WHEN conditions, but recheck passes and final status = 's2' +permutation "update1" "merge_status" "c2" "select1" "c1" + +# merge_status sees concurrently updated row and rechecks WHEN conditions, recheck fails, so final status = 's3' not 's2' +permutation "update2" "merge_status" "c2" "select1" "c1" + +# merge_status sees concurrently updated row and rechecks WHEN conditions, recheck fails, so final status = 's4' not 's2' +permutation "update3" "merge_status" "c2" "select1" "c1" + +# merge_status sees concurrently updated row and rechecks WHEN conditions, recheck fails, but we skip update and MERGE does nothing +permutation "update5" "merge_status" "c2" "select1" "c1" + +# merge_bal sees concurrently updated row and rechecks WHEN conditions, recheck fails, so final balance = 100 not 640 +permutation "update_bal1" "merge_bal" "c2" "select1" "c1" diff --git a/src/test/isolation/specs/merge-update.spec b/src/test/isolation/specs/merge-update.spec new file mode 100644 index 0000000000..e8d01666fe --- /dev/null +++ b/src/test/isolation/specs/merge-update.spec @@ -0,0 +1,156 @@ +# MERGE UPDATE +# +# This test exercises atypical cases +# 1. UPDATEs of PKs that change the join in the ON clause +# 2. UPDATEs with WHEN conditions that would fail after concurrent update +# 3. UPDATEs with extra ON conditions that would fail after concurrent update + +setup +{ + CREATE TABLE target (key int primary key, val text); + INSERT INTO target VALUES (1, 'setup1'); + + CREATE TABLE pa_target (key integer, val text) + PARTITION BY LIST (key); + CREATE TABLE part1 (key integer, val text); + CREATE TABLE part2 (val text, key integer); + CREATE TABLE part3 (key integer, val text); + + ALTER TABLE pa_target ATTACH PARTITION part1 FOR VALUES IN (1,4); + ALTER TABLE pa_target ATTACH PARTITION part2 FOR VALUES IN (2,5,6); + ALTER TABLE pa_target ATTACH PARTITION part3 DEFAULT; + + INSERT INTO pa_target VALUES (1, 'initial'); + INSERT INTO pa_target VALUES (2, 'initial'); +} + +teardown +{ + DROP TABLE target; + DROP TABLE pa_target CASCADE; +} + +session "s1" +setup +{ + BEGIN ISOLATION LEVEL READ COMMITTED; +} +step "merge1" +{ + MERGE INTO target t + USING (SELECT 1 as key, 'merge1' as val) s + ON s.key = t.key + WHEN NOT MATCHED THEN + INSERT VALUES (s.key, s.val) + WHEN MATCHED THEN + UPDATE set key = t.key + 1, val = t.val || ' updated by ' || s.val; +} +step "pa_merge1" +{ + MERGE INTO pa_target t + USING (SELECT 1 as key, 'pa_merge1' as val) s + ON s.key = t.key + WHEN NOT MATCHED THEN + INSERT VALUES (s.key, s.val) + WHEN MATCHED THEN + UPDATE set val = t.val || ' updated by ' || s.val; +} +step "pa_merge2" +{ + MERGE INTO pa_target t + USING (SELECT 1 as key, 'pa_merge2' as val) s + ON s.key = t.key + WHEN NOT MATCHED THEN + INSERT VALUES (s.key, s.val) + WHEN MATCHED THEN + UPDATE set key = t.key + 1, val = t.val || ' updated by ' || s.val; +} +step "pa_merge3" +{ + MERGE INTO pa_target t + USING (SELECT 1 as key, 'pa_merge2' as val) s + ON s.key = t.key + WHEN NOT MATCHED THEN + INSERT VALUES (s.key, s.val) + WHEN MATCHED THEN + UPDATE set val = 'prefix ' || t.val; +} +step "c1" { COMMIT; } +step "a1" { ABORT; } + +session "s2" +setup +{ + BEGIN ISOLATION LEVEL READ COMMITTED; +} +step "merge2a" +{ + MERGE INTO target t + USING (SELECT 1 as key, 'merge2a' as val) s + ON s.key = t.key + WHEN NOT MATCHED THEN + INSERT VALUES (s.key, s.val) + WHEN MATCHED THEN + UPDATE set key = t.key + 1, val = t.val || ' updated by ' || s.val; +} +step "merge2b" +{ + MERGE INTO target t + USING (SELECT 1 as key, 'merge2b' as val) s + ON s.key = t.key + WHEN NOT MATCHED THEN + INSERT VALUES (s.key, s.val) + WHEN MATCHED AND t.key < 2 THEN + UPDATE set key = t.key + 1, val = t.val || ' updated by ' || s.val; +} +step "merge2c" +{ + MERGE INTO target t + USING (SELECT 1 as key, 'merge2c' as val) s + ON s.key = t.key AND t.key < 2 + WHEN NOT MATCHED THEN + INSERT VALUES (s.key, s.val) + WHEN MATCHED THEN + UPDATE set key = t.key + 1, val = t.val || ' updated by ' || s.val; +} +step "pa_merge2a" +{ + MERGE INTO pa_target t + USING (SELECT 1 as key, 'pa_merge2a' as val) s + ON s.key = t.key + WHEN NOT MATCHED THEN + INSERT VALUES (s.key, s.val) + WHEN MATCHED THEN + UPDATE set key = t.key + 1, val = t.val || ' updated by ' || s.val; +} +# MERGE proceeds only if 'val' unchanged +step "pa_merge2b_when" +{ + MERGE INTO pa_target t + USING (SELECT 1 as key, 'pa_merge2b_when' as val) s + ON s.key = t.key + WHEN NOT MATCHED THEN + INSERT VALUES (s.key, s.val) + WHEN MATCHED AND t.val like 'initial%' THEN + UPDATE set key = t.key + 1, val = t.val || ' updated by ' || s.val; +} +step "select2" { SELECT * FROM target; } +step "pa_select2" { SELECT * FROM pa_target; } +step "c2" { COMMIT; } + +# Basic effects +permutation "merge1" "c1" "select2" "c2" + +# One after the other, no concurrency +permutation "merge1" "c1" "merge2a" "select2" "c2" + +# Now with concurrency +permutation "merge1" "merge2a" "c1" "select2" "c2" +permutation "merge1" "merge2a" "a1" "select2" "c2" +permutation "merge1" "merge2b" "c1" "select2" "c2" +permutation "merge1" "merge2c" "c1" "select2" "c2" +permutation "pa_merge1" "pa_merge2a" "c1" "pa_select2" "c2" +permutation "pa_merge2" "pa_merge2a" "c1" "pa_select2" "c2" # fails +permutation "pa_merge2" "c1" "pa_merge2a" "pa_select2" "c2" # succeeds +permutation "pa_merge3" "pa_merge2b_when" "c1" "pa_select2" "c2" # WHEN not satisfied by updated tuple +permutation "pa_merge1" "pa_merge2b_when" "c1" "pa_select2" "c2" # WHEN satisfied by updated tuple diff --git a/src/test/regress/expected/identity.out b/src/test/regress/expected/identity.out index 99811570b7..5f03d8e14f 100644 --- a/src/test/regress/expected/identity.out +++ b/src/test/regress/expected/identity.out @@ -560,3 +560,57 @@ CREATE TABLE itest15 (id integer GENERATED ALWAYS AS IDENTITY NOT NULL); DROP TABLE itest15; CREATE TABLE itest15 (id integer NOT NULL GENERATED ALWAYS AS IDENTITY); DROP TABLE itest15; +-- MERGE tests +CREATE TABLE itest15 (a int GENERATED ALWAYS AS IDENTITY, b text); +CREATE TABLE itest16 (a int GENERATED BY DEFAULT AS IDENTITY, b text); +MERGE INTO itest15 t +USING (SELECT 10 AS s_a, 'inserted by merge' AS s_b) s +ON t.a = s.s_a +WHEN NOT MATCHED THEN + INSERT (a, b) VALUES (s.s_a, s.s_b); +ERROR: cannot insert a non-DEFAULT value into column "a" +DETAIL: Column "a" is an identity column defined as GENERATED ALWAYS. +HINT: Use OVERRIDING SYSTEM VALUE to override. +-- Used to fail, but now it works and ignores the user supplied value +MERGE INTO itest15 t +USING (SELECT 20 AS s_a, 'inserted by merge' AS s_b) s +ON t.a = s.s_a +WHEN NOT MATCHED THEN + INSERT (a, b) OVERRIDING USER VALUE VALUES (s.s_a, s.s_b); +MERGE INTO itest15 t +USING (SELECT 30 AS s_a, 'inserted by merge' AS s_b) s +ON t.a = s.s_a +WHEN NOT MATCHED THEN + INSERT (a, b) OVERRIDING SYSTEM VALUE VALUES (s.s_a, s.s_b); +MERGE INTO itest16 t +USING (SELECT 10 AS s_a, 'inserted by merge' AS s_b) s +ON t.a = s.s_a +WHEN NOT MATCHED THEN + INSERT (a, b) VALUES (s.s_a, s.s_b); +MERGE INTO itest16 t +USING (SELECT 20 AS s_a, 'inserted by merge' AS s_b) s +ON t.a = s.s_a +WHEN NOT MATCHED THEN + INSERT (a, b) OVERRIDING USER VALUE VALUES (s.s_a, s.s_b); +MERGE INTO itest16 t +USING (SELECT 30 AS s_a, 'inserted by merge' AS s_b) s +ON t.a = s.s_a +WHEN NOT MATCHED THEN + INSERT (a, b) OVERRIDING SYSTEM VALUE VALUES (s.s_a, s.s_b); +SELECT * FROM itest15; + a | b +----+------------------- + 1 | inserted by merge + 30 | inserted by merge +(2 rows) + +SELECT * FROM itest16; + a | b +----+------------------- + 10 | inserted by merge + 1 | inserted by merge + 30 | inserted by merge +(3 rows) + +DROP TABLE itest15; +DROP TABLE itest16; diff --git a/src/test/regress/expected/merge.out b/src/test/regress/expected/merge.out new file mode 100644 index 0000000000..da8796986f --- /dev/null +++ b/src/test/regress/expected/merge.out @@ -0,0 +1,1934 @@ +-- +-- MERGE +-- +--\set VERBOSITY verbose +--set debug_print_rewritten = true; +--set debug_print_parse = true; +--set debug_print_pretty = true; +CREATE USER merge_privs; +CREATE USER merge_no_privs; +DROP TABLE IF EXISTS target; +NOTICE: table "target" does not exist, skipping +DROP TABLE IF EXISTS source; +NOTICE: table "source" does not exist, skipping +CREATE TABLE target (tid integer, balance integer); +CREATE TABLE source (sid integer, delta integer); --no index +INSERT INTO target VALUES (1, 10); +INSERT INTO target VALUES (2, 20); +INSERT INTO target VALUES (3, 30); +SELECT t.ctid is not null as matched, t.*, s.* FROM source s FULL OUTER JOIN target t ON s.sid = t.tid ORDER BY t.tid, s.sid; + matched | tid | balance | sid | delta +---------+-----+---------+-----+------- + t | 1 | 10 | | + t | 2 | 20 | | + t | 3 | 30 | | +(3 rows) + +ALTER TABLE target OWNER TO merge_privs; +ALTER TABLE source OWNER TO merge_privs; +CREATE TABLE target2 (tid integer, balance integer); +CREATE TABLE source2 (sid integer, delta integer); +ALTER TABLE target2 OWNER TO merge_no_privs; +ALTER TABLE source2 OWNER TO merge_no_privs; +GRANT INSERT ON target TO merge_no_privs; +SET SESSION AUTHORIZATION merge_privs; +EXPLAIN (COSTS OFF) +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN MATCHED THEN + DELETE; + QUERY PLAN +---------------------------------------- + Merge on target t + -> Merge Join + Merge Cond: (t.tid = s.sid) + -> Sort + Sort Key: t.tid + -> Seq Scan on target t + -> Sort + Sort Key: s.sid + -> Seq Scan on source s +(9 rows) + +-- +-- Errors +-- +MERGE INTO target t RANDOMWORD +USING source AS s +ON t.tid = s.sid +WHEN MATCHED THEN + UPDATE SET balance = 0; +ERROR: syntax error at or near "RANDOMWORD" +LINE 1: MERGE INTO target t RANDOMWORD + ^ +-- MATCHED/INSERT error +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN MATCHED THEN + INSERT DEFAULT VALUES; +ERROR: syntax error at or near "INSERT" +LINE 5: INSERT DEFAULT VALUES; + ^ +-- incorrectly specifying INTO target +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN NOT MATCHED THEN + INSERT INTO target DEFAULT VALUES; +ERROR: syntax error at or near "INTO" +LINE 5: INSERT INTO target DEFAULT VALUES; + ^ +-- Multiple VALUES clause +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN NOT MATCHED THEN + INSERT VALUES (1,1), (2,2); +ERROR: syntax error at or near "," +LINE 5: INSERT VALUES (1,1), (2,2); + ^ +-- SELECT query for INSERT +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN NOT MATCHED THEN + INSERT SELECT (1, 1); +ERROR: syntax error at or near "SELECT" +LINE 5: INSERT SELECT (1, 1); + ^ +-- NOT MATCHED/UPDATE +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN NOT MATCHED THEN + UPDATE SET balance = 0; +ERROR: syntax error at or near "UPDATE" +LINE 5: UPDATE SET balance = 0; + ^ +-- UPDATE tablename +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN MATCHED THEN + UPDATE target SET balance = 0; +ERROR: syntax error at or near "target" +LINE 5: UPDATE target SET balance = 0; + ^ +-- source and target names the same +MERGE INTO target +USING target +ON tid = tid +WHEN MATCHED THEN DO NOTHING; +ERROR: name "target" specified more than once +DETAIL: The name is used both as MERGE target table and data source. +-- unsupported relation types +-- view +CREATE VIEW tv AS SELECT * FROM target; +MERGE INTO tv t +USING source s +ON t.tid = s.sid +WHEN NOT MATCHED THEN + INSERT DEFAULT VALUES; +ERROR: cannot execute MERGE on relation "tv" +DETAIL: This operation is not supported for views. +DROP VIEW tv; +-- materialized view +CREATE MATERIALIZED VIEW mv AS SELECT * FROM target; +MERGE INTO mv t +USING source s +ON t.tid = s.sid +WHEN NOT MATCHED THEN + INSERT DEFAULT VALUES; +ERROR: cannot execute MERGE on relation "mv" +DETAIL: This operation is not supported for materialized views. +DROP MATERIALIZED VIEW mv; +-- permissions +MERGE INTO target +USING source2 +ON target.tid = source2.sid +WHEN MATCHED THEN + UPDATE SET balance = 0; +ERROR: permission denied for table source2 +GRANT INSERT ON target TO merge_no_privs; +SET SESSION AUTHORIZATION merge_no_privs; +MERGE INTO target +USING source2 +ON target.tid = source2.sid +WHEN MATCHED THEN + UPDATE SET balance = 0; +ERROR: permission denied for table target +GRANT UPDATE ON target2 TO merge_privs; +SET SESSION AUTHORIZATION merge_privs; +MERGE INTO target2 +USING source +ON target2.tid = source.sid +WHEN MATCHED THEN + DELETE; +ERROR: permission denied for table target2 +MERGE INTO target2 +USING source +ON target2.tid = source.sid +WHEN NOT MATCHED THEN + INSERT DEFAULT VALUES; +ERROR: permission denied for table target2 +-- check if the target can be accessed from source relation subquery; we should +-- not be able to do so +MERGE INTO target t +USING (SELECT * FROM source WHERE t.tid > sid) s +ON t.tid = s.sid +WHEN NOT MATCHED THEN + INSERT DEFAULT VALUES; +ERROR: invalid reference to FROM-clause entry for table "t" +LINE 2: USING (SELECT * FROM source WHERE t.tid > sid) s + ^ +HINT: There is an entry for table "t", but it cannot be referenced from this part of the query. +-- +-- initial tests +-- +-- zero rows in source has no effect +MERGE INTO target +USING source +ON target.tid = source.sid +WHEN MATCHED THEN + UPDATE SET balance = 0; +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN MATCHED THEN + UPDATE SET balance = 0; +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN MATCHED THEN + DELETE; +BEGIN; +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN NOT MATCHED THEN + INSERT DEFAULT VALUES; +ROLLBACK; +-- insert some non-matching source rows to work from +INSERT INTO source VALUES (4, 40); +SELECT * FROM source ORDER BY sid; + sid | delta +-----+------- + 4 | 40 +(1 row) + +SELECT * FROM target ORDER BY tid; + tid | balance +-----+--------- + 1 | 10 + 2 | 20 + 3 | 30 +(3 rows) + +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN NOT MATCHED THEN + DO NOTHING; +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN MATCHED THEN + UPDATE SET balance = 0; +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN MATCHED THEN + DELETE; +BEGIN; +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN NOT MATCHED THEN + INSERT DEFAULT VALUES; +SELECT * FROM target ORDER BY tid; + tid | balance +-----+--------- + 1 | 10 + 2 | 20 + 3 | 30 + | +(4 rows) + +ROLLBACK; +-- index plans +INSERT INTO target SELECT generate_series(1000,2500), 0; +ALTER TABLE target ADD PRIMARY KEY (tid); +ANALYZE target; +EXPLAIN (COSTS OFF) +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN MATCHED THEN + UPDATE SET balance = 0; + QUERY PLAN +---------------------------------------- + Merge on target t + -> Hash Join + Hash Cond: (s.sid = t.tid) + -> Seq Scan on source s + -> Hash + -> Seq Scan on target t +(6 rows) + +EXPLAIN (COSTS OFF) +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN MATCHED THEN + DELETE; + QUERY PLAN +---------------------------------------- + Merge on target t + -> Hash Join + Hash Cond: (s.sid = t.tid) + -> Seq Scan on source s + -> Hash + -> Seq Scan on target t +(6 rows) + +EXPLAIN (COSTS OFF) +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN NOT MATCHED THEN + INSERT VALUES (4, NULL); + QUERY PLAN +---------------------------------------- + Merge on target t + -> Hash Left Join + Hash Cond: (s.sid = t.tid) + -> Seq Scan on source s + -> Hash + -> Seq Scan on target t +(6 rows) + +DELETE FROM target WHERE tid > 100; +ANALYZE target; +-- insert some matching source rows to work from +INSERT INTO source VALUES (2, 5); +INSERT INTO source VALUES (3, 20); +SELECT * FROM source ORDER BY sid; + sid | delta +-----+------- + 2 | 5 + 3 | 20 + 4 | 40 +(3 rows) + +SELECT * FROM target ORDER BY tid; + tid | balance +-----+--------- + 1 | 10 + 2 | 20 + 3 | 30 +(3 rows) + +-- equivalent of an UPDATE join +BEGIN; +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN MATCHED THEN + UPDATE SET balance = 0; +SELECT * FROM target ORDER BY tid; + tid | balance +-----+--------- + 1 | 10 + 2 | 0 + 3 | 0 +(3 rows) + +ROLLBACK; +-- equivalent of a DELETE join +BEGIN; +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN MATCHED THEN + DELETE; +SELECT * FROM target ORDER BY tid; + tid | balance +-----+--------- + 1 | 10 +(1 row) + +ROLLBACK; +BEGIN; +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN MATCHED THEN + DO NOTHING; +SELECT * FROM target ORDER BY tid; + tid | balance +-----+--------- + 1 | 10 + 2 | 20 + 3 | 30 +(3 rows) + +ROLLBACK; +BEGIN; +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN NOT MATCHED THEN + INSERT VALUES (4, NULL); +SELECT * FROM target ORDER BY tid; + tid | balance +-----+--------- + 1 | 10 + 2 | 20 + 3 | 30 + 4 | +(4 rows) + +ROLLBACK; +-- duplicate source row causes multiple target row update ERROR +INSERT INTO source VALUES (2, 5); +SELECT * FROM source ORDER BY sid; + sid | delta +-----+------- + 2 | 5 + 2 | 5 + 3 | 20 + 4 | 40 +(4 rows) + +SELECT * FROM target ORDER BY tid; + tid | balance +-----+--------- + 1 | 10 + 2 | 20 + 3 | 30 +(3 rows) + +BEGIN; +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN MATCHED THEN + UPDATE SET balance = 0; +ERROR: MERGE command cannot affect row a second time +HINT: Ensure that not more than one source row matches any one target row. +ROLLBACK; +BEGIN; +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN MATCHED THEN + DELETE; +ERROR: MERGE command cannot affect row a second time +HINT: Ensure that not more than one source row matches any one target row. +ROLLBACK; +-- remove duplicate MATCHED data from source data +DELETE FROM source WHERE sid = 2; +INSERT INTO source VALUES (2, 5); +SELECT * FROM source ORDER BY sid; + sid | delta +-----+------- + 2 | 5 + 3 | 20 + 4 | 40 +(3 rows) + +SELECT * FROM target ORDER BY tid; + tid | balance +-----+--------- + 1 | 10 + 2 | 20 + 3 | 30 +(3 rows) + +-- duplicate source row on INSERT should fail because of target_pkey +INSERT INTO source VALUES (4, 40); +BEGIN; +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN NOT MATCHED THEN + INSERT VALUES (4, NULL); +ERROR: duplicate key value violates unique constraint "target_pkey" +DETAIL: Key (tid)=(4) already exists. +SELECT * FROM target ORDER BY tid; +ERROR: current transaction is aborted, commands ignored until end of transaction block +ROLLBACK; +-- remove duplicate NOT MATCHED data from source data +DELETE FROM source WHERE sid = 4; +INSERT INTO source VALUES (4, 40); +SELECT * FROM source ORDER BY sid; + sid | delta +-----+------- + 2 | 5 + 3 | 20 + 4 | 40 +(3 rows) + +SELECT * FROM target ORDER BY tid; + tid | balance +-----+--------- + 1 | 10 + 2 | 20 + 3 | 30 +(3 rows) + +-- remove constraints +alter table target drop CONSTRAINT target_pkey; +alter table target alter column tid drop not null; +-- multiple actions +BEGIN; +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN NOT MATCHED THEN + INSERT VALUES (4, 4) +WHEN MATCHED THEN + UPDATE SET balance = 0; +SELECT * FROM target ORDER BY tid; + tid | balance +-----+--------- + 1 | 10 + 2 | 0 + 3 | 0 + 4 | 4 +(4 rows) + +ROLLBACK; +-- should be equivalent +BEGIN; +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN MATCHED THEN + UPDATE SET balance = 0 +WHEN NOT MATCHED THEN + INSERT VALUES (4, 4); +SELECT * FROM target ORDER BY tid; + tid | balance +-----+--------- + 1 | 10 + 2 | 0 + 3 | 0 + 4 | 4 +(4 rows) + +ROLLBACK; +-- column references +-- do a simple equivalent of an UPDATE join +BEGIN; +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN MATCHED THEN + UPDATE SET balance = t.balance + s.delta; +SELECT * FROM target ORDER BY tid; + tid | balance +-----+--------- + 1 | 10 + 2 | 25 + 3 | 50 +(3 rows) + +ROLLBACK; +-- do a simple equivalent of an INSERT SELECT +BEGIN; +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN NOT MATCHED THEN + INSERT VALUES (s.sid, s.delta); +SELECT * FROM target ORDER BY tid; + tid | balance +-----+--------- + 1 | 10 + 2 | 20 + 3 | 30 + 4 | 40 +(4 rows) + +ROLLBACK; +-- and again with duplicate source rows +INSERT INTO source VALUES (5, 50); +INSERT INTO source VALUES (5, 50); +-- do a simple equivalent of an INSERT SELECT +BEGIN; +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN NOT MATCHED THEN + INSERT VALUES (s.sid, s.delta); +SELECT * FROM target ORDER BY tid; + tid | balance +-----+--------- + 1 | 10 + 2 | 20 + 3 | 30 + 4 | 40 + 5 | 50 + 5 | 50 +(6 rows) + +ROLLBACK; +-- removing duplicate source rows +DELETE FROM source WHERE sid = 5; +-- and again with explicitly identified column list +BEGIN; +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN NOT MATCHED THEN + INSERT (tid, balance) VALUES (s.sid, s.delta); +SELECT * FROM target ORDER BY tid; + tid | balance +-----+--------- + 1 | 10 + 2 | 20 + 3 | 30 + 4 | 40 +(4 rows) + +ROLLBACK; +-- and again with a subtle error: referring to non-existent target row for NOT MATCHED +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN NOT MATCHED THEN + INSERT (tid, balance) VALUES (t.tid, s.delta); +ERROR: invalid reference to FROM-clause entry for table "t" +LINE 5: INSERT (tid, balance) VALUES (t.tid, s.delta); + ^ +HINT: There is an entry for table "t", but it cannot be referenced from this part of the query. +-- and again with a constant ON clause +BEGIN; +MERGE INTO target t +USING source AS s +ON (SELECT true) +WHEN NOT MATCHED THEN + INSERT (tid, balance) VALUES (t.tid, s.delta); +ERROR: invalid reference to FROM-clause entry for table "t" +LINE 5: INSERT (tid, balance) VALUES (t.tid, s.delta); + ^ +HINT: There is an entry for table "t", but it cannot be referenced from this part of the query. +SELECT * FROM target ORDER BY tid; +ERROR: current transaction is aborted, commands ignored until end of transaction block +ROLLBACK; +-- now the classic UPSERT +BEGIN; +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN MATCHED THEN + UPDATE SET balance = t.balance + s.delta +WHEN NOT MATCHED THEN + INSERT VALUES (s.sid, s.delta); +SELECT * FROM target ORDER BY tid; + tid | balance +-----+--------- + 1 | 10 + 2 | 25 + 3 | 50 + 4 | 40 +(4 rows) + +ROLLBACK; +-- unreachable WHEN clause should ERROR +BEGIN; +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN MATCHED THEN /* Terminal WHEN clause for MATCHED */ + DELETE +WHEN MATCHED AND s.delta > 0 THEN + UPDATE SET balance = t.balance - s.delta; +ERROR: unreachable WHEN clause specified after unconditional WHEN clause +ROLLBACK; +-- conditional WHEN clause +CREATE TABLE wq_target (tid integer not null, balance integer DEFAULT -1); +CREATE TABLE wq_source (balance integer, sid integer); +INSERT INTO wq_source (sid, balance) VALUES (1, 100); +BEGIN; +-- try a simple INSERT with default values first +MERGE INTO wq_target t +USING wq_source s ON t.tid = s.sid +WHEN NOT MATCHED THEN + INSERT (tid) VALUES (s.sid); +SELECT * FROM wq_target; + tid | balance +-----+--------- + 1 | -1 +(1 row) + +ROLLBACK; +-- this time with a FALSE condition +MERGE INTO wq_target t +USING wq_source s ON t.tid = s.sid +WHEN NOT MATCHED AND FALSE THEN + INSERT (tid) VALUES (s.sid); +SELECT * FROM wq_target; + tid | balance +-----+--------- +(0 rows) + +-- this time with an actual condition which returns false +MERGE INTO wq_target t +USING wq_source s ON t.tid = s.sid +WHEN NOT MATCHED AND s.balance <> 100 THEN + INSERT (tid) VALUES (s.sid); +SELECT * FROM wq_target; + tid | balance +-----+--------- +(0 rows) + +BEGIN; +-- and now with a condition which returns true +MERGE INTO wq_target t +USING wq_source s ON t.tid = s.sid +WHEN NOT MATCHED AND s.balance = 100 THEN + INSERT (tid) VALUES (s.sid); +SELECT * FROM wq_target; + tid | balance +-----+--------- + 1 | -1 +(1 row) + +ROLLBACK; +-- conditions in the NOT MATCHED clause can only refer to source columns +BEGIN; +MERGE INTO wq_target t +USING wq_source s ON t.tid = s.sid +WHEN NOT MATCHED AND t.balance = 100 THEN + INSERT (tid) VALUES (s.sid); +ERROR: invalid reference to FROM-clause entry for table "t" +LINE 3: WHEN NOT MATCHED AND t.balance = 100 THEN + ^ +HINT: There is an entry for table "t", but it cannot be referenced from this part of the query. +SELECT * FROM wq_target; +ERROR: current transaction is aborted, commands ignored until end of transaction block +ROLLBACK; +MERGE INTO wq_target t +USING wq_source s ON t.tid = s.sid +WHEN NOT MATCHED AND s.balance = 100 THEN + INSERT (tid) VALUES (s.sid); +SELECT * FROM wq_target; + tid | balance +-----+--------- + 1 | -1 +(1 row) + +-- conditions in MATCHED clause can refer to both source and target +SELECT * FROM wq_source; + balance | sid +---------+----- + 100 | 1 +(1 row) + +MERGE INTO wq_target t +USING wq_source s ON t.tid = s.sid +WHEN MATCHED AND s.balance = 100 THEN + UPDATE SET balance = t.balance + s.balance; +SELECT * FROM wq_target; + tid | balance +-----+--------- + 1 | 99 +(1 row) + +MERGE INTO wq_target t +USING wq_source s ON t.tid = s.sid +WHEN MATCHED AND t.balance = 100 THEN + UPDATE SET balance = t.balance + s.balance; +SELECT * FROM wq_target; + tid | balance +-----+--------- + 1 | 99 +(1 row) + +-- check if AND works +MERGE INTO wq_target t +USING wq_source s ON t.tid = s.sid +WHEN MATCHED AND t.balance = 99 AND s.balance > 100 THEN + UPDATE SET balance = t.balance + s.balance; +SELECT * FROM wq_target; + tid | balance +-----+--------- + 1 | 99 +(1 row) + +MERGE INTO wq_target t +USING wq_source s ON t.tid = s.sid +WHEN MATCHED AND t.balance = 99 AND s.balance = 100 THEN + UPDATE SET balance = t.balance + s.balance; +SELECT * FROM wq_target; + tid | balance +-----+--------- + 1 | 199 +(1 row) + +-- check if OR works +MERGE INTO wq_target t +USING wq_source s ON t.tid = s.sid +WHEN MATCHED AND t.balance = 99 OR s.balance > 100 THEN + UPDATE SET balance = t.balance + s.balance; +SELECT * FROM wq_target; + tid | balance +-----+--------- + 1 | 199 +(1 row) + +MERGE INTO wq_target t +USING wq_source s ON t.tid = s.sid +WHEN MATCHED AND t.balance = 199 OR s.balance > 100 THEN + UPDATE SET balance = t.balance + s.balance; +SELECT * FROM wq_target; + tid | balance +-----+--------- + 1 | 299 +(1 row) + +-- check if subqueries work in the conditions? +MERGE INTO wq_target t +USING wq_source s ON t.tid = s.sid +WHEN MATCHED AND t.balance > (SELECT max(balance) FROM target) THEN + UPDATE SET balance = t.balance + s.balance; +-- check if we can access system columns in the conditions +MERGE INTO wq_target t +USING wq_source s ON t.tid = s.sid +WHEN MATCHED AND t.xmin = t.xmax THEN + UPDATE SET balance = t.balance + s.balance; +ERROR: cannot use system column "xmin" in MERGE WHEN condition +LINE 3: WHEN MATCHED AND t.xmin = t.xmax THEN + ^ +MERGE INTO wq_target t +USING wq_source s ON t.tid = s.sid +WHEN MATCHED AND t.tableoid >= 0 THEN + UPDATE SET balance = t.balance + s.balance; +SELECT * FROM wq_target; + tid | balance +-----+--------- + 1 | 499 +(1 row) + +-- test preventing WHEN conditions from writing to the database +create or replace function merge_when_and_write() returns boolean +language plpgsql as +$$ +BEGIN + INSERT INTO target VALUES (100, 100); + RETURN TRUE; +END; +$$; +BEGIN; +MERGE INTO wq_target t +USING wq_source s ON t.tid = s.sid +WHEN MATCHED AND (merge_when_and_write()) THEN + UPDATE SET balance = t.balance + s.balance; +ROLLBACK; +drop function merge_when_and_write(); +DROP TABLE wq_target, wq_source; +-- test triggers +create or replace function merge_trigfunc () returns trigger +language plpgsql as +$$ +DECLARE + line text; +BEGIN + SELECT INTO line format('%s %s %s trigger%s', + TG_WHEN, TG_OP, TG_LEVEL, CASE + WHEN TG_OP = 'INSERT' AND TG_LEVEL = 'ROW' + THEN format(' row: %s', NEW) + WHEN TG_OP = 'UPDATE' AND TG_LEVEL = 'ROW' + THEN format(' row: %s -> %s', OLD, NEW) + WHEN TG_OP = 'DELETE' AND TG_LEVEL = 'ROW' + THEN format(' row: %s', OLD) + END); + + RAISE NOTICE '%', line; + IF (TG_WHEN = 'BEFORE' AND TG_LEVEL = 'ROW') THEN + IF (TG_OP = 'DELETE') THEN + RETURN OLD; + ELSE + RETURN NEW; + END IF; + ELSE + RETURN NULL; + END IF; +END; +$$; +CREATE TRIGGER merge_bsi BEFORE INSERT ON target FOR EACH STATEMENT EXECUTE PROCEDURE merge_trigfunc (); +CREATE TRIGGER merge_bsu BEFORE UPDATE ON target FOR EACH STATEMENT EXECUTE PROCEDURE merge_trigfunc (); +CREATE TRIGGER merge_bsd BEFORE DELETE ON target FOR EACH STATEMENT EXECUTE PROCEDURE merge_trigfunc (); +CREATE TRIGGER merge_asi AFTER INSERT ON target FOR EACH STATEMENT EXECUTE PROCEDURE merge_trigfunc (); +CREATE TRIGGER merge_asu AFTER UPDATE ON target FOR EACH STATEMENT EXECUTE PROCEDURE merge_trigfunc (); +CREATE TRIGGER merge_asd AFTER DELETE ON target FOR EACH STATEMENT EXECUTE PROCEDURE merge_trigfunc (); +CREATE TRIGGER merge_bri BEFORE INSERT ON target FOR EACH ROW EXECUTE PROCEDURE merge_trigfunc (); +CREATE TRIGGER merge_bru BEFORE UPDATE ON target FOR EACH ROW EXECUTE PROCEDURE merge_trigfunc (); +CREATE TRIGGER merge_brd BEFORE DELETE ON target FOR EACH ROW EXECUTE PROCEDURE merge_trigfunc (); +CREATE TRIGGER merge_ari AFTER INSERT ON target FOR EACH ROW EXECUTE PROCEDURE merge_trigfunc (); +CREATE TRIGGER merge_aru AFTER UPDATE ON target FOR EACH ROW EXECUTE PROCEDURE merge_trigfunc (); +CREATE TRIGGER merge_ard AFTER DELETE ON target FOR EACH ROW EXECUTE PROCEDURE merge_trigfunc (); +-- now the classic UPSERT, with a DELETE +BEGIN; +UPDATE target SET balance = 0 WHERE tid = 3; +NOTICE: BEFORE UPDATE STATEMENT trigger +NOTICE: BEFORE UPDATE ROW trigger row: (3,30) -> (3,0) +NOTICE: AFTER UPDATE ROW trigger row: (3,30) -> (3,0) +NOTICE: AFTER UPDATE STATEMENT trigger +--EXPLAIN (ANALYZE ON, COSTS OFF, SUMMARY OFF, TIMING OFF) +MERGE INTO target 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 THEN + INSERT VALUES (s.sid, s.delta); +NOTICE: BEFORE INSERT STATEMENT trigger +NOTICE: BEFORE UPDATE STATEMENT trigger +NOTICE: BEFORE DELETE STATEMENT trigger +NOTICE: BEFORE DELETE ROW trigger row: (3,0) +NOTICE: BEFORE UPDATE ROW trigger row: (2,20) -> (2,15) +NOTICE: BEFORE INSERT ROW trigger row: (4,40) +NOTICE: AFTER DELETE ROW trigger row: (3,0) +NOTICE: AFTER UPDATE ROW trigger row: (2,20) -> (2,15) +NOTICE: AFTER INSERT ROW trigger row: (4,40) +NOTICE: AFTER DELETE STATEMENT trigger +NOTICE: AFTER UPDATE STATEMENT trigger +NOTICE: AFTER INSERT STATEMENT trigger +SELECT * FROM target ORDER BY tid; + tid | balance +-----+--------- + 1 | 10 + 2 | 15 + 4 | 40 +(3 rows) + +ROLLBACK; +-- Test behavior of triggers that turn UPDATE/DELETE into no-ops +create or replace function skip_merge_op() returns trigger +language plpgsql as +$$ +BEGIN + RETURN NULL; +END; +$$; +SELECT * FROM target full outer join source on (sid = tid); + tid | balance | sid | delta +-----+---------+-----+------- + 3 | 30 | 3 | 20 + 2 | 20 | 2 | 5 + | | 4 | 40 + 1 | 10 | | +(4 rows) + +create trigger merge_skip BEFORE INSERT OR UPDATE or DELETE + ON target FOR EACH ROW EXECUTE FUNCTION skip_merge_op(); +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN MATCHED AND s.sid = 3 THEN UPDATE SET balance = t.balance + s.delta +WHEN MATCHED THEN DELETE +WHEN NOT MATCHED THEN INSERT VALUES (sid, delta); +NOTICE: BEFORE INSERT STATEMENT trigger +NOTICE: BEFORE UPDATE STATEMENT trigger +NOTICE: BEFORE DELETE STATEMENT trigger +NOTICE: BEFORE UPDATE ROW trigger row: (3,30) -> (3,50) +NOTICE: BEFORE DELETE ROW trigger row: (2,20) +NOTICE: BEFORE INSERT ROW trigger row: (4,40) +NOTICE: AFTER DELETE STATEMENT trigger +NOTICE: AFTER UPDATE STATEMENT trigger +NOTICE: AFTER INSERT STATEMENT trigger +SELECT * FROM target FULL OUTER JOIN source ON (sid = tid); + tid | balance | sid | delta +-----+---------+-----+------- + 3 | 30 | 3 | 20 + 2 | 20 | 2 | 5 + | | 4 | 40 + 1 | 10 | | +(4 rows) + +DROP TRIGGER merge_skip ON target; +DROP FUNCTION skip_merge_op(); +-- test from PL/pgSQL +-- make sure MERGE INTO isn't interpreted to mean returning variables like SELECT INTO +BEGIN; +DO LANGUAGE plpgsql $$ +BEGIN +MERGE INTO target 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; +END; +$$; +NOTICE: BEFORE UPDATE STATEMENT trigger +NOTICE: BEFORE UPDATE ROW trigger row: (3,30) -> (3,10) +NOTICE: BEFORE UPDATE ROW trigger row: (2,20) -> (2,15) +NOTICE: AFTER UPDATE ROW trigger row: (3,30) -> (3,10) +NOTICE: AFTER UPDATE ROW trigger row: (2,20) -> (2,15) +NOTICE: AFTER UPDATE STATEMENT trigger +ROLLBACK; +--source constants +BEGIN; +MERGE INTO target t +USING (SELECT 9 AS sid, 57 AS delta) AS s +ON t.tid = s.sid +WHEN NOT MATCHED THEN + INSERT (tid, balance) VALUES (s.sid, s.delta); +NOTICE: BEFORE INSERT STATEMENT trigger +NOTICE: BEFORE INSERT ROW trigger row: (9,57) +NOTICE: AFTER INSERT ROW trigger row: (9,57) +NOTICE: AFTER INSERT STATEMENT trigger +SELECT * FROM target ORDER BY tid; + tid | balance +-----+--------- + 1 | 10 + 2 | 20 + 3 | 30 + 9 | 57 +(4 rows) + +ROLLBACK; +--source query +BEGIN; +MERGE INTO target t +USING (SELECT sid, delta FROM source WHERE delta > 0) AS s +ON t.tid = s.sid +WHEN NOT MATCHED THEN + INSERT (tid, balance) VALUES (s.sid, s.delta); +NOTICE: BEFORE INSERT STATEMENT trigger +NOTICE: BEFORE INSERT ROW trigger row: (4,40) +NOTICE: AFTER INSERT ROW trigger row: (4,40) +NOTICE: AFTER INSERT STATEMENT trigger +SELECT * FROM target ORDER BY tid; + tid | balance +-----+--------- + 1 | 10 + 2 | 20 + 3 | 30 + 4 | 40 +(4 rows) + +ROLLBACK; +BEGIN; +MERGE INTO target t +USING (SELECT sid, delta as newname FROM source WHERE delta > 0) AS s +ON t.tid = s.sid +WHEN NOT MATCHED THEN + INSERT (tid, balance) VALUES (s.sid, s.newname); +NOTICE: BEFORE INSERT STATEMENT trigger +NOTICE: BEFORE INSERT ROW trigger row: (4,40) +NOTICE: AFTER INSERT ROW trigger row: (4,40) +NOTICE: AFTER INSERT STATEMENT trigger +SELECT * FROM target ORDER BY tid; + tid | balance +-----+--------- + 1 | 10 + 2 | 20 + 3 | 30 + 4 | 40 +(4 rows) + +ROLLBACK; +--self-merge +BEGIN; +MERGE INTO target t1 +USING target t2 +ON t1.tid = t2.tid +WHEN MATCHED THEN + UPDATE SET balance = t1.balance + t2.balance +WHEN NOT MATCHED THEN + INSERT VALUES (t2.tid, t2.balance); +NOTICE: BEFORE INSERT STATEMENT trigger +NOTICE: BEFORE UPDATE STATEMENT trigger +NOTICE: BEFORE UPDATE ROW trigger row: (1,10) -> (1,20) +NOTICE: BEFORE UPDATE ROW trigger row: (2,20) -> (2,40) +NOTICE: BEFORE UPDATE ROW trigger row: (3,30) -> (3,60) +NOTICE: AFTER UPDATE ROW trigger row: (1,10) -> (1,20) +NOTICE: AFTER UPDATE ROW trigger row: (2,20) -> (2,40) +NOTICE: AFTER UPDATE ROW trigger row: (3,30) -> (3,60) +NOTICE: AFTER UPDATE STATEMENT trigger +NOTICE: AFTER INSERT STATEMENT trigger +SELECT * FROM target ORDER BY tid; + tid | balance +-----+--------- + 1 | 20 + 2 | 40 + 3 | 60 +(3 rows) + +ROLLBACK; +BEGIN; +MERGE INTO target t +USING (SELECT tid as sid, balance as delta FROM target WHERE balance > 0) AS s +ON t.tid = s.sid +WHEN NOT MATCHED THEN + INSERT (tid, balance) VALUES (s.sid, s.delta); +NOTICE: BEFORE INSERT STATEMENT trigger +NOTICE: AFTER INSERT STATEMENT trigger +SELECT * FROM target ORDER BY tid; + tid | balance +-----+--------- + 1 | 10 + 2 | 20 + 3 | 30 +(3 rows) + +ROLLBACK; +BEGIN; +MERGE INTO target t +USING +(SELECT sid, max(delta) AS delta + FROM source + GROUP BY sid + HAVING count(*) = 1 + ORDER BY sid ASC) AS s +ON t.tid = s.sid +WHEN NOT MATCHED THEN + INSERT (tid, balance) VALUES (s.sid, s.delta); +NOTICE: BEFORE INSERT STATEMENT trigger +NOTICE: BEFORE INSERT ROW trigger row: (4,40) +NOTICE: AFTER INSERT ROW trigger row: (4,40) +NOTICE: AFTER INSERT STATEMENT trigger +SELECT * FROM target ORDER BY tid; + tid | balance +-----+--------- + 1 | 10 + 2 | 20 + 3 | 30 + 4 | 40 +(4 rows) + +ROLLBACK; +-- plpgsql parameters and results +BEGIN; +CREATE FUNCTION merge_func (p_id integer, p_bal integer) +RETURNS INTEGER +LANGUAGE plpgsql +AS $$ +DECLARE + result integer; +BEGIN +MERGE INTO target t +USING (SELECT p_id AS sid) AS s +ON t.tid = s.sid +WHEN MATCHED THEN + UPDATE SET balance = t.balance - p_bal; +IF FOUND THEN + GET DIAGNOSTICS result := ROW_COUNT; +END IF; +RETURN result; +END; +$$; +SELECT merge_func(3, 4); +NOTICE: BEFORE UPDATE STATEMENT trigger +NOTICE: BEFORE UPDATE ROW trigger row: (3,30) -> (3,26) +NOTICE: AFTER UPDATE ROW trigger row: (3,30) -> (3,26) +NOTICE: AFTER UPDATE STATEMENT trigger + merge_func +------------ + 1 +(1 row) + +SELECT * FROM target ORDER BY tid; + tid | balance +-----+--------- + 1 | 10 + 2 | 20 + 3 | 26 +(3 rows) + +ROLLBACK; +-- PREPARE +BEGIN; +prepare foom as merge into target t using (select 1 as sid) s on (t.tid = s.sid) when matched then update set balance = 1; +execute foom; +NOTICE: BEFORE UPDATE STATEMENT trigger +NOTICE: BEFORE UPDATE ROW trigger row: (1,10) -> (1,1) +NOTICE: AFTER UPDATE ROW trigger row: (1,10) -> (1,1) +NOTICE: AFTER UPDATE STATEMENT trigger +SELECT * FROM target ORDER BY tid; + tid | balance +-----+--------- + 1 | 1 + 2 | 20 + 3 | 30 +(3 rows) + +ROLLBACK; +BEGIN; +PREPARE foom2 (integer, integer) AS +MERGE INTO target t +USING (SELECT 1) s +ON t.tid = $1 +WHEN MATCHED THEN +UPDATE SET balance = $2; +--EXPLAIN (ANALYZE ON, COSTS OFF, SUMMARY OFF, TIMING OFF) +execute foom2 (1, 1); +NOTICE: BEFORE UPDATE STATEMENT trigger +NOTICE: BEFORE UPDATE ROW trigger row: (1,10) -> (1,1) +NOTICE: AFTER UPDATE ROW trigger row: (1,10) -> (1,1) +NOTICE: AFTER UPDATE STATEMENT trigger +SELECT * FROM target ORDER BY tid; + tid | balance +-----+--------- + 1 | 1 + 2 | 20 + 3 | 30 +(3 rows) + +ROLLBACK; +-- subqueries in source relation +CREATE TABLE sq_target (tid integer NOT NULL, balance integer); +CREATE TABLE sq_source (delta integer, sid integer, balance integer DEFAULT 0); +INSERT INTO sq_target(tid, balance) VALUES (1,100), (2,200), (3,300); +INSERT INTO sq_source(sid, delta) VALUES (1,10), (2,20), (4,40); +BEGIN; +MERGE INTO sq_target t +USING (SELECT * FROM sq_source) s +ON tid = sid +WHEN MATCHED AND t.balance > delta THEN + UPDATE SET balance = t.balance + delta; +SELECT * FROM sq_target; + tid | balance +-----+--------- + 3 | 300 + 1 | 110 + 2 | 220 +(3 rows) + +ROLLBACK; +-- try a view +CREATE VIEW v AS SELECT * FROM sq_source WHERE sid < 2; +BEGIN; +MERGE INTO sq_target +USING v +ON tid = sid +WHEN MATCHED THEN + UPDATE SET balance = v.balance + delta; +SELECT * FROM sq_target; + tid | balance +-----+--------- + 2 | 200 + 3 | 300 + 1 | 10 +(3 rows) + +ROLLBACK; +-- ambiguous reference to a column +BEGIN; +MERGE INTO sq_target +USING v +ON tid = sid +WHEN MATCHED AND tid > 2 THEN + UPDATE SET balance = balance + delta +WHEN NOT MATCHED THEN + INSERT (balance, tid) VALUES (balance + delta, sid) +WHEN MATCHED AND tid < 2 THEN + DELETE; +ERROR: column reference "balance" is ambiguous +LINE 5: UPDATE SET balance = balance + delta + ^ +ROLLBACK; +BEGIN; +INSERT INTO sq_source (sid, balance, delta) VALUES (-1, -1, -10); +MERGE INTO sq_target t +USING v +ON tid = sid +WHEN MATCHED AND tid > 2 THEN + UPDATE SET balance = t.balance + delta +WHEN NOT MATCHED THEN + INSERT (balance, tid) VALUES (balance + delta, sid) +WHEN MATCHED AND tid < 2 THEN + DELETE; +SELECT * FROM sq_target; + tid | balance +-----+--------- + 2 | 200 + 3 | 300 + -1 | -11 +(3 rows) + +ROLLBACK; +-- CTEs +BEGIN; +INSERT INTO sq_source (sid, balance, delta) VALUES (-1, -1, -10); +WITH targq AS ( + SELECT * FROM v +) +MERGE INTO sq_target t +USING v +ON tid = sid +WHEN MATCHED AND tid > 2 THEN + UPDATE SET balance = t.balance + delta +WHEN NOT MATCHED THEN + INSERT (balance, tid) VALUES (balance + delta, sid) +WHEN MATCHED AND tid < 2 THEN + DELETE; +ROLLBACK; +-- RETURNING +BEGIN; +INSERT INTO sq_source (sid, balance, delta) VALUES (-1, -1, -10); +MERGE INTO sq_target t +USING v +ON tid = sid +WHEN MATCHED AND tid > 2 THEN + UPDATE SET balance = t.balance + delta +WHEN NOT MATCHED THEN + INSERT (balance, tid) VALUES (balance + delta, sid) +WHEN MATCHED AND tid < 2 THEN + DELETE +RETURNING *; +ERROR: syntax error at or near "RETURNING" +LINE 10: RETURNING *; + ^ +ROLLBACK; +-- EXPLAIN +CREATE TABLE ex_mtarget (a int, b int); +CREATE TABLE ex_msource (a int, b int); +INSERT INTO ex_mtarget SELECT i, i*10 FROM generate_series(1,100,2) i; +INSERT INTO ex_msource SELECT i, i*10 FROM generate_series(1,100,1) i; +CREATE FUNCTION explain_merge(query text) RETURNS SETOF text +LANGUAGE plpgsql AS +$$ +DECLARE ln text; +BEGIN + FOR ln IN + EXECUTE 'explain (analyze, timing off, summary off, costs off) ' || + query + LOOP + ln := regexp_replace(ln, 'Memory: \S*', 'Memory: xxx'); + RETURN NEXT ln; + END LOOP; +END; +$$; +-- only updates +SELECT explain_merge(' +MERGE INTO ex_mtarget t USING ex_msource s ON t.a = s.a +WHEN MATCHED THEN + UPDATE SET b = t.b + 1'); + explain_merge +---------------------------------------------------------------------- + Merge on ex_mtarget t (actual rows=0 loops=1) + Tuples Inserted: 0 + Tuples Updated: 50 + Tuples Deleted: 0 + Tuples Skipped: 0 + -> Merge Join (actual rows=50 loops=1) + Merge Cond: (t.a = s.a) + -> Sort (actual rows=50 loops=1) + Sort Key: t.a + Sort Method: quicksort Memory: xxx + -> Seq Scan on ex_mtarget t (actual rows=50 loops=1) + -> Sort (actual rows=100 loops=1) + Sort Key: s.a + Sort Method: quicksort Memory: xxx + -> Seq Scan on ex_msource s (actual rows=100 loops=1) +(15 rows) + +-- only updates to selected tuples +SELECT explain_merge(' +MERGE INTO ex_mtarget t USING ex_msource s ON t.a = s.a +WHEN MATCHED AND t.a < 10 THEN + UPDATE SET b = t.b + 1'); + explain_merge +---------------------------------------------------------------------- + Merge on ex_mtarget t (actual rows=0 loops=1) + Tuples Inserted: 0 + Tuples Updated: 5 + Tuples Deleted: 0 + Tuples Skipped: 45 + -> Merge Join (actual rows=50 loops=1) + Merge Cond: (t.a = s.a) + -> Sort (actual rows=50 loops=1) + Sort Key: t.a + Sort Method: quicksort Memory: xxx + -> Seq Scan on ex_mtarget t (actual rows=50 loops=1) + -> Sort (actual rows=100 loops=1) + Sort Key: s.a + Sort Method: quicksort Memory: xxx + -> Seq Scan on ex_msource s (actual rows=100 loops=1) +(15 rows) + +-- updates + deletes +SELECT explain_merge(' +MERGE INTO ex_mtarget t USING ex_msource s ON t.a = s.a +WHEN MATCHED AND t.a < 10 THEN + UPDATE SET b = t.b + 1 +WHEN MATCHED AND t.a >= 10 AND t.a <= 20 THEN + DELETE'); + explain_merge +---------------------------------------------------------------------- + Merge on ex_mtarget t (actual rows=0 loops=1) + Tuples Inserted: 0 + Tuples Updated: 5 + Tuples Deleted: 5 + Tuples Skipped: 40 + -> Merge Join (actual rows=50 loops=1) + Merge Cond: (t.a = s.a) + -> Sort (actual rows=50 loops=1) + Sort Key: t.a + Sort Method: quicksort Memory: xxx + -> Seq Scan on ex_mtarget t (actual rows=50 loops=1) + -> Sort (actual rows=100 loops=1) + Sort Key: s.a + Sort Method: quicksort Memory: xxx + -> Seq Scan on ex_msource s (actual rows=100 loops=1) +(15 rows) + +-- only inserts +SELECT explain_merge(' +MERGE INTO ex_mtarget t USING ex_msource s ON t.a = s.a +WHEN NOT MATCHED AND s.a < 10 THEN + INSERT VALUES (a, b)'); + explain_merge +---------------------------------------------------------------------- + Merge on ex_mtarget t (actual rows=0 loops=1) + Tuples Inserted: 4 + Tuples Updated: 0 + Tuples Deleted: 0 + Tuples Skipped: 96 + -> Merge Left Join (actual rows=100 loops=1) + Merge Cond: (s.a = t.a) + -> Sort (actual rows=100 loops=1) + Sort Key: s.a + Sort Method: quicksort Memory: xxx + -> Seq Scan on ex_msource s (actual rows=100 loops=1) + -> Sort (actual rows=45 loops=1) + Sort Key: t.a + Sort Method: quicksort Memory: xxx + -> Seq Scan on ex_mtarget t (actual rows=45 loops=1) +(15 rows) + +-- all three +SELECT explain_merge(' +MERGE INTO ex_mtarget t USING ex_msource s ON t.a = s.a +WHEN MATCHED AND t.a < 10 THEN + UPDATE SET b = t.b + 1 +WHEN MATCHED AND t.a >= 30 AND t.a <= 40 THEN + DELETE +WHEN NOT MATCHED AND s.a < 20 THEN + INSERT VALUES (a, b)'); + explain_merge +---------------------------------------------------------------------- + Merge on ex_mtarget t (actual rows=0 loops=1) + Tuples Inserted: 10 + Tuples Updated: 9 + Tuples Deleted: 5 + Tuples Skipped: 76 + -> Merge Left Join (actual rows=100 loops=1) + Merge Cond: (s.a = t.a) + -> Sort (actual rows=100 loops=1) + Sort Key: s.a + Sort Method: quicksort Memory: xxx + -> Seq Scan on ex_msource s (actual rows=100 loops=1) + -> Sort (actual rows=49 loops=1) + Sort Key: t.a + Sort Method: quicksort Memory: xxx + -> Seq Scan on ex_mtarget t (actual rows=49 loops=1) +(15 rows) + +DROP TABLE ex_msource, ex_mtarget; +DROP FUNCTION explain_merge(text); +-- Subqueries +BEGIN; +MERGE INTO sq_target t +USING v +ON tid = sid +WHEN MATCHED THEN + UPDATE SET balance = (SELECT count(*) FROM sq_target); +SELECT * FROM sq_target WHERE tid = 1; + tid | balance +-----+--------- + 1 | 3 +(1 row) + +ROLLBACK; +BEGIN; +MERGE INTO sq_target t +USING v +ON tid = sid +WHEN MATCHED AND (SELECT count(*) > 0 FROM sq_target) THEN + UPDATE SET balance = 42; +SELECT * FROM sq_target WHERE tid = 1; + tid | balance +-----+--------- + 1 | 42 +(1 row) + +ROLLBACK; +BEGIN; +MERGE INTO sq_target t +USING v +ON tid = sid AND (SELECT count(*) > 0 FROM sq_target) +WHEN MATCHED THEN + UPDATE SET balance = 42; +SELECT * FROM sq_target WHERE tid = 1; + tid | balance +-----+--------- + 1 | 42 +(1 row) + +ROLLBACK; +DROP TABLE sq_target, sq_source CASCADE; +NOTICE: drop cascades to view v +CREATE TABLE pa_target (tid integer, balance float, val text) + PARTITION BY LIST (tid); +CREATE TABLE part1 PARTITION OF pa_target FOR VALUES IN (1,4); +CREATE TABLE part2 PARTITION OF pa_target FOR VALUES IN (2,5,6); +CREATE TABLE part3 PARTITION OF pa_target FOR VALUES IN (3,8,9); +CREATE TABLE part4 PARTITION OF pa_target DEFAULT; +CREATE TABLE pa_source (sid integer, delta float); +-- insert many rows to the source table +INSERT INTO pa_source SELECT id, id * 10 FROM generate_series(1,14) AS id; +-- insert a few rows in the target table (odd numbered tid) +INSERT INTO pa_target SELECT id, id * 100, 'initial' FROM generate_series(1,14,2) AS id; +-- try simple MERGE +BEGIN; +MERGE INTO pa_target t + USING pa_source s + ON t.tid = s.sid + WHEN MATCHED THEN + UPDATE SET balance = balance + delta, val = val || ' updated by merge' + WHEN NOT MATCHED THEN + INSERT VALUES (sid, delta, 'inserted by merge'); +SELECT * FROM pa_target ORDER BY tid; + tid | balance | val +-----+---------+-------------------------- + 1 | 110 | initial updated by merge + 2 | 20 | inserted by merge + 3 | 330 | initial updated by merge + 4 | 40 | inserted by merge + 5 | 550 | initial updated by merge + 6 | 60 | inserted by merge + 7 | 770 | initial updated by merge + 8 | 80 | inserted by merge + 9 | 990 | initial updated by merge + 10 | 100 | inserted by merge + 11 | 1210 | initial updated by merge + 12 | 120 | inserted by merge + 13 | 1430 | initial updated by merge + 14 | 140 | inserted by merge +(14 rows) + +ROLLBACK; +-- same with a constant qual +BEGIN; +MERGE INTO pa_target t + USING pa_source s + ON t.tid = s.sid AND tid = 1 + WHEN MATCHED THEN + UPDATE SET balance = balance + delta, val = val || ' updated by merge' + WHEN NOT MATCHED THEN + INSERT VALUES (sid, delta, 'inserted by merge'); +SELECT * FROM pa_target ORDER BY tid; + tid | balance | val +-----+---------+-------------------------- + 1 | 110 | initial updated by merge + 2 | 20 | inserted by merge + 3 | 30 | inserted by merge + 3 | 300 | initial + 4 | 40 | inserted by merge + 5 | 500 | initial + 5 | 50 | inserted by merge + 6 | 60 | inserted by merge + 7 | 700 | initial + 7 | 70 | inserted by merge + 8 | 80 | inserted by merge + 9 | 90 | inserted by merge + 9 | 900 | initial + 10 | 100 | inserted by merge + 11 | 1100 | initial + 11 | 110 | inserted by merge + 12 | 120 | inserted by merge + 13 | 1300 | initial + 13 | 130 | inserted by merge + 14 | 140 | inserted by merge +(20 rows) + +ROLLBACK; +-- try updating the partition key column +BEGIN; +MERGE INTO pa_target t + USING pa_source s + ON t.tid = s.sid + WHEN MATCHED THEN + UPDATE SET tid = tid + 1, balance = balance + delta, val = val || ' updated by merge' + WHEN NOT MATCHED THEN + INSERT VALUES (sid, delta, 'inserted by merge'); +SELECT * FROM pa_target ORDER BY tid; + tid | balance | val +-----+---------+-------------------------- + 2 | 110 | initial updated by merge + 2 | 20 | inserted by merge + 4 | 40 | inserted by merge + 4 | 330 | initial updated by merge + 6 | 550 | initial updated by merge + 6 | 60 | inserted by merge + 8 | 80 | inserted by merge + 8 | 770 | initial updated by merge + 10 | 990 | initial updated by merge + 10 | 100 | inserted by merge + 12 | 1210 | initial updated by merge + 12 | 120 | inserted by merge + 14 | 1430 | initial updated by merge + 14 | 140 | inserted by merge +(14 rows) + +ROLLBACK; +DROP TABLE pa_target CASCADE; +-- The target table is partitioned in the same way, but this time by attaching +-- partitions which have columns in different order, dropped columns etc. +CREATE TABLE pa_target (tid integer, balance float, val text) + PARTITION BY LIST (tid); +CREATE TABLE part1 (tid integer, balance float, val text); +CREATE TABLE part2 (balance float, tid integer, val text); +CREATE TABLE part3 (tid integer, balance float, val text); +CREATE TABLE part4 (extraid text, tid integer, balance float, val text); +ALTER TABLE part4 DROP COLUMN extraid; +ALTER TABLE pa_target ATTACH PARTITION part1 FOR VALUES IN (1,4); +ALTER TABLE pa_target ATTACH PARTITION part2 FOR VALUES IN (2,5,6); +ALTER TABLE pa_target ATTACH PARTITION part3 FOR VALUES IN (3,8,9); +ALTER TABLE pa_target ATTACH PARTITION part4 DEFAULT; +-- insert a few rows in the target table (odd numbered tid) +INSERT INTO pa_target SELECT id, id * 100, 'initial' FROM generate_series(1,14,2) AS id; +-- try simple MERGE +BEGIN; +MERGE INTO pa_target t + USING pa_source s + ON t.tid = s.sid + WHEN MATCHED THEN + UPDATE SET balance = balance + delta, val = val || ' updated by merge' + WHEN NOT MATCHED THEN + INSERT VALUES (sid, delta, 'inserted by merge'); +SELECT * FROM pa_target ORDER BY tid; + tid | balance | val +-----+---------+-------------------------- + 1 | 110 | initial updated by merge + 2 | 20 | inserted by merge + 3 | 330 | initial updated by merge + 4 | 40 | inserted by merge + 5 | 550 | initial updated by merge + 6 | 60 | inserted by merge + 7 | 770 | initial updated by merge + 8 | 80 | inserted by merge + 9 | 990 | initial updated by merge + 10 | 100 | inserted by merge + 11 | 1210 | initial updated by merge + 12 | 120 | inserted by merge + 13 | 1430 | initial updated by merge + 14 | 140 | inserted by merge +(14 rows) + +ROLLBACK; +-- same with a constant qual +BEGIN; +MERGE INTO pa_target t + USING pa_source s + ON t.tid = s.sid AND tid IN (1, 5) + WHEN MATCHED AND tid % 5 = 0 THEN DELETE + WHEN MATCHED THEN + UPDATE SET balance = balance + delta, val = val || ' updated by merge' + WHEN NOT MATCHED THEN + INSERT VALUES (sid, delta, 'inserted by merge'); +SELECT * FROM pa_target ORDER BY tid; + tid | balance | val +-----+---------+-------------------------- + 1 | 110 | initial updated by merge + 2 | 20 | inserted by merge + 3 | 30 | inserted by merge + 3 | 300 | initial + 4 | 40 | inserted by merge + 6 | 60 | inserted by merge + 7 | 700 | initial + 7 | 70 | inserted by merge + 8 | 80 | inserted by merge + 9 | 900 | initial + 9 | 90 | inserted by merge + 10 | 100 | inserted by merge + 11 | 110 | inserted by merge + 11 | 1100 | initial + 12 | 120 | inserted by merge + 13 | 1300 | initial + 13 | 130 | inserted by merge + 14 | 140 | inserted by merge +(18 rows) + +ROLLBACK; +-- try updating the partition key column +BEGIN; +MERGE INTO pa_target t + USING pa_source s + ON t.tid = s.sid + WHEN MATCHED THEN + UPDATE SET tid = tid + 1, balance = balance + delta, val = val || ' updated by merge' + WHEN NOT MATCHED THEN + INSERT VALUES (sid, delta, 'inserted by merge'); +SELECT * FROM pa_target ORDER BY tid; + tid | balance | val +-----+---------+-------------------------- + 2 | 110 | initial updated by merge + 2 | 20 | inserted by merge + 4 | 40 | inserted by merge + 4 | 330 | initial updated by merge + 6 | 550 | initial updated by merge + 6 | 60 | inserted by merge + 8 | 80 | inserted by merge + 8 | 770 | initial updated by merge + 10 | 990 | initial updated by merge + 10 | 100 | inserted by merge + 12 | 1210 | initial updated by merge + 12 | 120 | inserted by merge + 14 | 1430 | initial updated by merge + 14 | 140 | inserted by merge +(14 rows) + +ROLLBACK; +DROP TABLE pa_source; +DROP TABLE pa_target CASCADE; +-- Sub-partitioning +CREATE TABLE pa_target (logts timestamp, tid integer, balance float, val text) + PARTITION BY RANGE (logts); +CREATE TABLE part_m01 PARTITION OF pa_target + FOR VALUES FROM ('2017-01-01') TO ('2017-02-01') + PARTITION BY LIST (tid); +CREATE TABLE part_m01_odd PARTITION OF part_m01 + FOR VALUES IN (1,3,5,7,9); +CREATE TABLE part_m01_even PARTITION OF part_m01 + FOR VALUES IN (2,4,6,8); +CREATE TABLE part_m02 PARTITION OF pa_target + FOR VALUES FROM ('2017-02-01') TO ('2017-03-01') + PARTITION BY LIST (tid); +CREATE TABLE part_m02_odd PARTITION OF part_m02 + FOR VALUES IN (1,3,5,7,9); +CREATE TABLE part_m02_even PARTITION OF part_m02 + FOR VALUES IN (2,4,6,8); +CREATE TABLE pa_source (sid integer, delta float); +-- insert many rows to the source table +INSERT INTO pa_source SELECT id, id * 10 FROM generate_series(1,14) AS id; +-- insert a few rows in the target table (odd numbered tid) +INSERT INTO pa_target SELECT '2017-01-31', id, id * 100, 'initial' FROM generate_series(1,9,3) AS id; +INSERT INTO pa_target SELECT '2017-02-28', id, id * 100, 'initial' FROM generate_series(2,9,3) AS id; +-- try simple MERGE +BEGIN; +MERGE INTO pa_target t + USING (SELECT '2017-01-15' AS slogts, * FROM pa_source WHERE sid < 10) s + ON t.tid = s.sid + WHEN MATCHED THEN + UPDATE SET balance = balance + delta, val = val || ' updated by merge' + WHEN NOT MATCHED THEN + INSERT VALUES (slogts::timestamp, sid, delta, 'inserted by merge'); +SELECT * FROM pa_target ORDER BY tid; + logts | tid | balance | val +--------------------------+-----+---------+-------------------------- + Tue Jan 31 00:00:00 2017 | 1 | 110 | initial updated by merge + Tue Feb 28 00:00:00 2017 | 2 | 220 | initial updated by merge + Sun Jan 15 00:00:00 2017 | 3 | 30 | inserted by merge + Tue Jan 31 00:00:00 2017 | 4 | 440 | initial updated by merge + Tue Feb 28 00:00:00 2017 | 5 | 550 | initial updated by merge + Sun Jan 15 00:00:00 2017 | 6 | 60 | inserted by merge + Tue Jan 31 00:00:00 2017 | 7 | 770 | initial updated by merge + Tue Feb 28 00:00:00 2017 | 8 | 880 | initial updated by merge + Sun Jan 15 00:00:00 2017 | 9 | 90 | inserted by merge +(9 rows) + +ROLLBACK; +DROP TABLE pa_source; +DROP TABLE pa_target CASCADE; +-- some complex joins on the source side +CREATE TABLE cj_target (tid integer, balance float, val text); +CREATE TABLE cj_source1 (sid1 integer, scat integer, delta integer); +CREATE TABLE cj_source2 (sid2 integer, sval text); +INSERT INTO cj_source1 VALUES (1, 10, 100); +INSERT INTO cj_source1 VALUES (1, 20, 200); +INSERT INTO cj_source1 VALUES (2, 20, 300); +INSERT INTO cj_source1 VALUES (3, 10, 400); +INSERT INTO cj_source2 VALUES (1, 'initial source2'); +INSERT INTO cj_source2 VALUES (2, 'initial source2'); +INSERT INTO cj_source2 VALUES (3, 'initial source2'); +-- source relation is an unaliased join +MERGE INTO cj_target t +USING cj_source1 s1 + INNER JOIN cj_source2 s2 ON sid1 = sid2 +ON t.tid = sid1 +WHEN NOT MATCHED THEN + INSERT VALUES (sid1, delta, sval); +-- try accessing columns from either side of the source join +MERGE INTO cj_target t +USING cj_source2 s2 + INNER JOIN cj_source1 s1 ON sid1 = sid2 AND scat = 20 +ON t.tid = sid1 +WHEN NOT MATCHED THEN + INSERT VALUES (sid2, delta, sval) +WHEN MATCHED THEN + DELETE; +-- some simple expressions in INSERT targetlist +MERGE INTO cj_target t +USING cj_source2 s2 + INNER JOIN cj_source1 s1 ON sid1 = sid2 +ON t.tid = sid1 +WHEN NOT MATCHED THEN + INSERT VALUES (sid2, delta + scat, sval) +WHEN MATCHED THEN + UPDATE SET val = val || ' updated by merge'; +MERGE INTO cj_target t +USING cj_source2 s2 + INNER JOIN cj_source1 s1 ON sid1 = sid2 AND scat = 20 +ON t.tid = sid1 +WHEN MATCHED THEN + UPDATE SET val = val || ' ' || delta::text; +SELECT * FROM cj_target; + tid | balance | val +-----+---------+---------------------------------- + 3 | 400 | initial source2 updated by merge + 1 | 220 | initial source2 200 + 1 | 110 | initial source2 200 + 2 | 320 | initial source2 300 +(4 rows) + +ALTER TABLE cj_source1 RENAME COLUMN sid1 TO sid; +ALTER TABLE cj_source2 RENAME COLUMN sid2 TO sid; +TRUNCATE cj_target; +MERGE INTO cj_target t +USING cj_source1 s1 + INNER JOIN cj_source2 s2 ON s1.sid = s2.sid +ON t.tid = s1.sid +WHEN NOT MATCHED THEN + INSERT VALUES (s2.sid, delta, sval); +DROP TABLE cj_source2, cj_source1, cj_target; +-- Function scans +CREATE TABLE fs_target (a int, b int, c text); +MERGE INTO fs_target t +USING generate_series(1,100,1) AS id +ON t.a = id +WHEN MATCHED THEN + UPDATE SET b = b + id +WHEN NOT MATCHED THEN + INSERT VALUES (id, -1); +MERGE INTO fs_target t +USING generate_series(1,100,2) AS id +ON t.a = id +WHEN MATCHED THEN + UPDATE SET b = b + id, c = 'updated '|| id.*::text +WHEN NOT MATCHED THEN + INSERT VALUES (id, -1, 'inserted ' || id.*::text); +SELECT count(*) FROM fs_target; + count +------- + 100 +(1 row) + +DROP TABLE fs_target; +-- SERIALIZABLE test +-- handled in isolation tests +-- Inheritance-based partitioning +CREATE TABLE measurement ( + city_id int not null, + logdate date not null, + peaktemp int, + unitsales int +); +CREATE TABLE measurement_y2006m02 ( + CHECK ( logdate >= DATE '2006-02-01' AND logdate < DATE '2006-03-01' ) +) INHERITS (measurement); +CREATE TABLE measurement_y2006m03 ( + CHECK ( logdate >= DATE '2006-03-01' AND logdate < DATE '2006-04-01' ) +) INHERITS (measurement); +CREATE TABLE measurement_y2007m01 ( + filler text, + peaktemp int, + logdate date not null, + city_id int not null, + unitsales int + CHECK ( logdate >= DATE '2007-01-01' AND logdate < DATE '2007-02-01') +); +ALTER TABLE measurement_y2007m01 DROP COLUMN filler; +ALTER TABLE measurement_y2007m01 INHERIT measurement; +CREATE OR REPLACE FUNCTION measurement_insert_trigger() +RETURNS TRIGGER AS $$ +BEGIN + IF ( NEW.logdate >= DATE '2006-02-01' AND + NEW.logdate < DATE '2006-03-01' ) THEN + INSERT INTO measurement_y2006m02 VALUES (NEW.*); + ELSIF ( NEW.logdate >= DATE '2006-03-01' AND + NEW.logdate < DATE '2006-04-01' ) THEN + INSERT INTO measurement_y2006m03 VALUES (NEW.*); + ELSIF ( NEW.logdate >= DATE '2007-01-01' AND + NEW.logdate < DATE '2007-02-01' ) THEN + INSERT INTO measurement_y2007m01 (city_id, logdate, peaktemp, unitsales) + VALUES (NEW.*); + ELSE + RAISE EXCEPTION 'Date out of range. Fix the measurement_insert_trigger() function!'; + END IF; + RETURN NULL; +END; +$$ LANGUAGE plpgsql ; +CREATE TRIGGER insert_measurement_trigger + BEFORE INSERT ON measurement + FOR EACH ROW EXECUTE PROCEDURE measurement_insert_trigger(); +INSERT INTO measurement VALUES (1, '2006-02-10', 35, 10); +INSERT INTO measurement VALUES (1, '2006-02-16', 45, 20); +INSERT INTO measurement VALUES (1, '2006-03-17', 25, 10); +INSERT INTO measurement VALUES (1, '2006-03-27', 15, 40); +INSERT INTO measurement VALUES (1, '2007-01-15', 10, 10); +INSERT INTO measurement VALUES (1, '2007-01-17', 10, 10); +SELECT tableoid::regclass, * FROM measurement ORDER BY city_id, logdate; + tableoid | city_id | logdate | peaktemp | unitsales +----------------------+---------+------------+----------+----------- + measurement_y2006m02 | 1 | 02-10-2006 | 35 | 10 + measurement_y2006m02 | 1 | 02-16-2006 | 45 | 20 + measurement_y2006m03 | 1 | 03-17-2006 | 25 | 10 + measurement_y2006m03 | 1 | 03-27-2006 | 15 | 40 + measurement_y2007m01 | 1 | 01-15-2007 | 10 | 10 + measurement_y2007m01 | 1 | 01-17-2007 | 10 | 10 +(6 rows) + +CREATE TABLE new_measurement (LIKE measurement); +INSERT INTO new_measurement VALUES (1, '2006-03-01', 20, 10); +INSERT INTO new_measurement VALUES (1, '2006-02-16', 50, 10); +INSERT INTO new_measurement VALUES (2, '2006-02-10', 20, 20); +INSERT INTO new_measurement VALUES (1, '2006-03-27', NULL, NULL); +INSERT INTO new_measurement VALUES (1, '2007-01-17', NULL, NULL); +INSERT INTO new_measurement VALUES (1, '2007-01-15', 5, NULL); +INSERT INTO new_measurement VALUES (1, '2007-01-16', 10, 10); +MERGE into measurement m + USING new_measurement nm ON + (m.city_id = nm.city_id and m.logdate=nm.logdate) +WHEN MATCHED AND nm.peaktemp IS NULL THEN DELETE +WHEN MATCHED THEN UPDATE + SET peaktemp = greatest(m.peaktemp, nm.peaktemp), + unitsales = m.unitsales + coalesce(nm.unitsales, 0) +WHEN NOT MATCHED THEN INSERT + (city_id, logdate, peaktemp, unitsales) + VALUES (city_id, logdate, peaktemp, unitsales); +SELECT tableoid::regclass, * FROM measurement ORDER BY city_id, logdate; + tableoid | city_id | logdate | peaktemp | unitsales +----------------------+---------+------------+----------+----------- + measurement_y2006m02 | 1 | 02-10-2006 | 35 | 10 + measurement_y2006m02 | 1 | 02-16-2006 | 50 | 30 + measurement_y2006m03 | 1 | 03-01-2006 | 20 | 10 + measurement_y2006m03 | 1 | 03-17-2006 | 25 | 10 + measurement_y2007m01 | 1 | 01-15-2007 | 10 | 10 + measurement_y2007m01 | 1 | 01-16-2007 | 10 | 10 + measurement_y2006m02 | 2 | 02-10-2006 | 20 | 20 +(7 rows) + +DROP TABLE measurement, new_measurement CASCADE; +NOTICE: drop cascades to 3 other objects +DETAIL: drop cascades to table measurement_y2006m02 +drop cascades to table measurement_y2006m03 +drop cascades to table measurement_y2007m01 +DROP FUNCTION measurement_insert_trigger(); +-- prepare +RESET SESSION AUTHORIZATION; +DROP TABLE target, target2; +DROP TABLE source, source2; +DROP FUNCTION merge_trigfunc(); +DROP USER merge_privs; +DROP USER merge_no_privs; diff --git a/src/test/regress/expected/privileges.out b/src/test/regress/expected/privileges.out index 291e21d7a6..8b4b039c6a 100644 --- a/src/test/regress/expected/privileges.out +++ b/src/test/regress/expected/privileges.out @@ -699,6 +699,104 @@ SELECT atest6 FROM atest6; -- ok (0 rows) COPY atest6 TO stdout; -- ok +-- test column privileges with MERGE +SET SESSION AUTHORIZATION regress_priv_user1; +CREATE TABLE mtarget (a int, b text); +CREATE TABLE msource (a int, b text); +INSERT INTO mtarget VALUES (1, 'init1'), (2, 'init2'); +INSERT INTO msource VALUES (1, 'source1'), (2, 'source2'), (3, 'source3'); +GRANT SELECT (a) ON msource TO regress_priv_user4; +GRANT SELECT (a) ON mtarget TO regress_priv_user4; +GRANT INSERT (a,b) ON mtarget TO regress_priv_user4; +GRANT UPDATE (b) ON mtarget TO regress_priv_user4; +SET SESSION AUTHORIZATION regress_priv_user4; +-- +-- test source privileges +-- +-- fail (no SELECT priv on s.b) +MERGE INTO mtarget t USING msource s ON t.a = s.a +WHEN MATCHED THEN + UPDATE SET b = s.b +WHEN NOT MATCHED THEN + INSERT VALUES (a, NULL); +ERROR: permission denied for table msource +-- fail (s.b used in the INSERTed values) +MERGE INTO mtarget t USING msource s ON t.a = s.a +WHEN MATCHED THEN + UPDATE SET b = 'x' +WHEN NOT MATCHED THEN + INSERT VALUES (a, b); +ERROR: permission denied for table msource +-- fail (s.b used in the WHEN quals) +MERGE INTO mtarget t USING msource s ON t.a = s.a +WHEN MATCHED AND s.b = 'x' THEN + UPDATE SET b = 'x' +WHEN NOT MATCHED THEN + INSERT VALUES (a, NULL); +ERROR: permission denied for table msource +-- this should be ok since only s.a is accessed +BEGIN; +MERGE INTO mtarget t USING msource s ON t.a = s.a +WHEN MATCHED THEN + UPDATE SET b = 'ok' +WHEN NOT MATCHED THEN + INSERT VALUES (a, NULL); +ROLLBACK; +SET SESSION AUTHORIZATION regress_priv_user1; +GRANT SELECT (b) ON msource TO regress_priv_user4; +SET SESSION AUTHORIZATION regress_priv_user4; +-- should now be ok +BEGIN; +MERGE INTO mtarget t USING msource s ON t.a = s.a +WHEN MATCHED THEN + UPDATE SET b = s.b +WHEN NOT MATCHED THEN + INSERT VALUES (a, b); +ROLLBACK; +-- +-- test target privileges +-- +-- fail (no SELECT priv on t.b) +MERGE INTO mtarget t USING msource s ON t.a = s.a +WHEN MATCHED THEN + UPDATE SET b = t.b +WHEN NOT MATCHED THEN + INSERT VALUES (a, NULL); +ERROR: permission denied for table mtarget +-- fail (no UPDATE on t.a) +MERGE INTO mtarget t USING msource s ON t.a = s.a +WHEN MATCHED THEN + UPDATE SET b = s.b, a = t.a + 1 +WHEN NOT MATCHED THEN + INSERT VALUES (a, b); +ERROR: permission denied for table mtarget +-- fail (no SELECT on t.b) +MERGE INTO mtarget t USING msource s ON t.a = s.a +WHEN MATCHED AND t.b IS NOT NULL THEN + UPDATE SET b = s.b +WHEN NOT MATCHED THEN + INSERT VALUES (a, b); +ERROR: permission denied for table mtarget +-- ok +BEGIN; +MERGE INTO mtarget t USING msource s ON t.a = s.a +WHEN MATCHED THEN + UPDATE SET b = s.b; +ROLLBACK; +-- fail (no DELETE) +MERGE INTO mtarget t USING msource s ON t.a = s.a +WHEN MATCHED AND t.b IS NOT NULL THEN + DELETE; +ERROR: permission denied for table mtarget +-- grant delete privileges +SET SESSION AUTHORIZATION regress_priv_user1; +GRANT DELETE ON mtarget TO regress_priv_user4; +-- should be ok now +BEGIN; +MERGE INTO mtarget t USING msource s ON t.a = s.a +WHEN MATCHED AND t.b IS NOT NULL THEN + DELETE; +ROLLBACK; -- check error reporting with column privs SET SESSION AUTHORIZATION regress_priv_user1; CREATE TABLE t1 (c1 int, c2 int, c3 int check (c3 < 5), primary key (c1, c2)); diff --git a/src/test/regress/expected/rowsecurity.out b/src/test/regress/expected/rowsecurity.out index d32a40ede3..b5f6eecba1 100644 --- a/src/test/regress/expected/rowsecurity.out +++ b/src/test/regress/expected/rowsecurity.out @@ -2117,6 +2117,188 @@ ERROR: new row violates row-level security policy (USING expression) for table INSERT INTO document VALUES (1, (SELECT cid from category WHERE cname = 'novel'), 1, 'regress_rls_bob', 'my first novel') ON CONFLICT (did) DO UPDATE SET dauthor = 'regress_rls_carol'; ERROR: new row violates row-level security policy for table "document" +-- +-- MERGE +-- +RESET SESSION AUTHORIZATION; +DROP POLICY p3_with_all ON document; +ALTER TABLE document ADD COLUMN dnotes text DEFAULT ''; +-- all documents are readable +CREATE POLICY p1 ON document FOR SELECT USING (true); +-- one may insert documents only authored by them +CREATE POLICY p2 ON document FOR INSERT WITH CHECK (dauthor = current_user); +-- one may only update documents in 'novel' category +CREATE POLICY p3 ON document FOR UPDATE + USING (cid = (SELECT cid from category WHERE cname = 'novel')) + WITH CHECK (dauthor = current_user); +-- one may only delete documents in 'manga' category +CREATE POLICY p4 ON document FOR DELETE + USING (cid = (SELECT cid from category WHERE cname = 'manga')); +SELECT * FROM document; + did | cid | dlevel | dauthor | dtitle | dnotes +-----+-----+--------+-------------------+----------------------------------+-------- + 1 | 11 | 1 | regress_rls_bob | my first novel | + 3 | 22 | 2 | regress_rls_bob | my science fiction | + 4 | 44 | 1 | regress_rls_bob | my first manga | + 5 | 44 | 2 | regress_rls_bob | my second manga | + 6 | 22 | 1 | regress_rls_carol | great science fiction | + 7 | 33 | 2 | regress_rls_carol | great technology book | + 8 | 44 | 1 | regress_rls_carol | great manga | + 9 | 22 | 1 | regress_rls_dave | awesome science fiction | + 10 | 33 | 2 | regress_rls_dave | awesome technology book | + 11 | 33 | 1 | regress_rls_carol | hoge | + 33 | 22 | 1 | regress_rls_bob | okay science fiction | + 2 | 11 | 2 | regress_rls_bob | my first novel | + 78 | 33 | 1 | regress_rls_bob | some technology novel | + 79 | 33 | 1 | regress_rls_bob | technology book, can only insert | +(14 rows) + +SET SESSION AUTHORIZATION regress_rls_bob; +-- Fails, since update violates WITH CHECK qual on dauthor +MERGE INTO document d +USING (SELECT 1 as sdid) s +ON did = s.sdid +WHEN MATCHED THEN + UPDATE SET dnotes = dnotes || ' notes added by merge1 ', dauthor = 'regress_rls_alice'; +ERROR: new row violates row-level security policy for table "document" +-- Should be OK since USING and WITH CHECK quals pass +MERGE INTO document d +USING (SELECT 1 as sdid) s +ON did = s.sdid +WHEN MATCHED THEN + UPDATE SET dnotes = dnotes || ' notes added by merge2 '; +-- Even when dauthor is updated explicitly, but to the existing value +MERGE INTO document d +USING (SELECT 1 as sdid) s +ON did = s.sdid +WHEN MATCHED THEN + UPDATE SET dnotes = dnotes || ' notes added by merge3 ', dauthor = 'regress_rls_bob'; +-- There is a MATCH for did = 3, but UPDATE's USING qual does not allow +-- updating an item in category 'science fiction' +MERGE INTO document d +USING (SELECT 3 as sdid) s +ON did = s.sdid +WHEN MATCHED THEN + UPDATE SET dnotes = dnotes || ' notes added by merge '; +ERROR: target row violates row-level security policy (USING expression) for table "document" +-- The same thing with DELETE action, but fails again because no permissions +-- to delete items in 'science fiction' category that did 3 belongs to. +MERGE INTO document d +USING (SELECT 3 as sdid) s +ON did = s.sdid +WHEN MATCHED THEN + DELETE; +ERROR: target row violates row-level security policy (USING expression) for table "document" +-- Document with did 4 belongs to 'manga' category which is allowed for +-- deletion. But this fails because the UPDATE action is matched first and +-- UPDATE policy does not allow updation in the category. +MERGE INTO document d +USING (SELECT 4 as sdid) s +ON did = s.sdid +WHEN MATCHED AND dnotes = '' THEN + UPDATE SET dnotes = dnotes || ' notes added by merge ' +WHEN MATCHED THEN + DELETE; +ERROR: target row violates row-level security policy (USING expression) for table "document" +-- UPDATE action is not matched this time because of the WHEN qual. +-- DELETE still fails because role regress_rls_bob does not have SELECT +-- privileges on 'manga' category row in the category table. +MERGE INTO document d +USING (SELECT 4 as sdid) s +ON did = s.sdid +WHEN MATCHED AND dnotes <> '' THEN + UPDATE SET dnotes = dnotes || ' notes added by merge ' +WHEN MATCHED THEN + DELETE; +ERROR: target row violates row-level security policy (USING expression) for table "document" +SELECT * FROM document WHERE did = 4; + did | cid | dlevel | dauthor | dtitle | dnotes +-----+-----+--------+-----------------+----------------+-------- + 4 | 44 | 1 | regress_rls_bob | my first manga | +(1 row) + +-- Switch to regress_rls_carol role and try the DELETE again. It should succeed +-- this time +RESET SESSION AUTHORIZATION; +SET SESSION AUTHORIZATION regress_rls_carol; +MERGE INTO document d +USING (SELECT 4 as sdid) s +ON did = s.sdid +WHEN MATCHED AND dnotes <> '' THEN + UPDATE SET dnotes = dnotes || ' notes added by merge ' +WHEN MATCHED THEN + DELETE; +-- Switch back to regress_rls_bob role +RESET SESSION AUTHORIZATION; +SET SESSION AUTHORIZATION regress_rls_bob; +-- Try INSERT action. This fails because we are trying to insert +-- dauthor = regress_rls_dave and INSERT's WITH CHECK does not allow +-- that +MERGE INTO document d +USING (SELECT 12 as sdid) s +ON did = s.sdid +WHEN MATCHED THEN + DELETE +WHEN NOT MATCHED THEN + INSERT VALUES (12, 11, 1, 'regress_rls_dave', 'another novel'); +ERROR: new row violates row-level security policy for table "document" +-- This should be fine +MERGE INTO document d +USING (SELECT 12 as sdid) s +ON did = s.sdid +WHEN MATCHED THEN + DELETE +WHEN NOT MATCHED THEN + INSERT VALUES (12, 11, 1, 'regress_rls_bob', 'another novel'); +-- ok +MERGE INTO document d +USING (SELECT 1 as sdid) s +ON did = s.sdid +WHEN MATCHED THEN + UPDATE SET dnotes = dnotes || ' notes added by merge4 ' +WHEN NOT MATCHED THEN + INSERT VALUES (12, 11, 1, 'regress_rls_bob', 'another novel'); +-- drop and create a new SELECT policy which prevents us from reading +-- any document except with category 'magna' +RESET SESSION AUTHORIZATION; +DROP POLICY p1 ON document; +CREATE POLICY p1 ON document FOR SELECT + USING (cid = (SELECT cid from category WHERE cname = 'manga')); +SET SESSION AUTHORIZATION regress_rls_bob; +-- MERGE can no longer see the matching row and hence attempts the +-- NOT MATCHED action, which results in unique key violation +MERGE INTO document d +USING (SELECT 1 as sdid) s +ON did = s.sdid +WHEN MATCHED THEN + UPDATE SET dnotes = dnotes || ' notes added by merge5 ' +WHEN NOT MATCHED THEN + INSERT VALUES (12, 11, 1, 'regress_rls_bob', 'another novel'); +ERROR: duplicate key value violates unique constraint "document_pkey" +RESET SESSION AUTHORIZATION; +-- drop the restrictive SELECT policy so that we can look at the +-- final state of the table +DROP POLICY p1 ON document; +-- Just check everything went per plan +SELECT * FROM document; + did | cid | dlevel | dauthor | dtitle | dnotes +-----+-----+--------+-------------------+----------------------------------+----------------------------------------------------------------------- + 3 | 22 | 2 | regress_rls_bob | my science fiction | + 5 | 44 | 2 | regress_rls_bob | my second manga | + 6 | 22 | 1 | regress_rls_carol | great science fiction | + 7 | 33 | 2 | regress_rls_carol | great technology book | + 8 | 44 | 1 | regress_rls_carol | great manga | + 9 | 22 | 1 | regress_rls_dave | awesome science fiction | + 10 | 33 | 2 | regress_rls_dave | awesome technology book | + 11 | 33 | 1 | regress_rls_carol | hoge | + 33 | 22 | 1 | regress_rls_bob | okay science fiction | + 2 | 11 | 2 | regress_rls_bob | my first novel | + 78 | 33 | 1 | regress_rls_bob | some technology novel | + 79 | 33 | 1 | regress_rls_bob | technology book, can only insert | + 12 | 11 | 1 | regress_rls_bob | another novel | + 1 | 11 | 1 | regress_rls_bob | my first novel | notes added by merge2 notes added by merge3 notes added by merge4 +(14 rows) + -- -- ROLE/GROUP -- diff --git a/src/test/regress/expected/rules.out b/src/test/regress/expected/rules.out index 27d19b4bf1..92e1a2f6d8 100644 --- a/src/test/regress/expected/rules.out +++ b/src/test/regress/expected/rules.out @@ -3476,6 +3476,38 @@ CREATE RULE rules_parted_table_insert AS ON INSERT to rules_parted_table ALTER RULE rules_parted_table_insert ON rules_parted_table RENAME TO rules_parted_table_insert_redirect; DROP TABLE rules_parted_table; -- +-- test MERGE +-- +CREATE TABLE rule_merge1 (a int, b text); +CREATE TABLE rule_merge2 (a int, b text); +CREATE RULE rule1 AS ON INSERT TO rule_merge1 + DO INSTEAD INSERT INTO rule_merge2 VALUES (NEW.*); +CREATE RULE rule2 AS ON UPDATE TO rule_merge1 + DO INSTEAD UPDATE rule_merge2 SET a = NEW.a, b = NEW.b + WHERE a = OLD.a; +CREATE RULE rule3 AS ON DELETE TO rule_merge1 + DO INSTEAD DELETE FROM rule_merge2 WHERE a = OLD.a; +-- MERGE not supported for table with rules +MERGE INTO rule_merge1 t USING (SELECT 1 AS a) s + ON t.a = s.a + WHEN MATCHED AND t.a < 2 THEN + UPDATE SET b = b || ' updated by merge' + WHEN MATCHED AND t.a > 2 THEN + DELETE + WHEN NOT MATCHED THEN + INSERT VALUES (s.a, ''); +ERROR: cannot execute MERGE on relation "rule_merge1" +DETAIL: MERGE is not supported for relations with rules. +-- should be ok with the other table though +MERGE INTO rule_merge2 t USING (SELECT 1 AS a) s + ON t.a = s.a + WHEN MATCHED AND t.a < 2 THEN + UPDATE SET b = b || ' updated by merge' + WHEN MATCHED AND t.a > 2 THEN + DELETE + WHEN NOT MATCHED THEN + INSERT VALUES (s.a, ''); +-- -- Test enabling/disabling -- CREATE TABLE ruletest1 (a int); diff --git a/src/test/regress/expected/triggers.out b/src/test/regress/expected/triggers.out index d3e02ca63b..cd812336f2 100644 --- a/src/test/regress/expected/triggers.out +++ b/src/test/regress/expected/triggers.out @@ -3284,6 +3284,54 @@ delete from self_ref where a = 1; NOTICE: trigger_func(self_ref) called: action = DELETE, when = BEFORE, level = STATEMENT NOTICE: trigger = self_ref_s_trig, old table = (1,), (2,1), (3,2), (4,3) drop table self_ref; +-- +-- test transition tables with MERGE +-- +create table merge_target_table (a int primary key, b text); +create trigger merge_target_table_insert_trig + after insert on merge_target_table referencing new table as new_table + for each statement execute procedure dump_insert(); +create trigger merge_target_table_update_trig + after update on merge_target_table referencing old table as old_table new table as new_table + for each statement execute procedure dump_update(); +create trigger merge_target_table_delete_trig + after delete on merge_target_table referencing old table as old_table + for each statement execute procedure dump_delete(); +create table merge_source_table (a int, b text); +insert into merge_source_table + values (1, 'initial1'), (2, 'initial2'), + (3, 'initial3'), (4, 'initial4'); +merge into merge_target_table t +using merge_source_table s +on t.a = s.a +when not matched then + insert values (a, b); +NOTICE: trigger = merge_target_table_insert_trig, new table = (1,initial1), (2,initial2), (3,initial3), (4,initial4) +merge into merge_target_table t +using merge_source_table s +on t.a = s.a +when matched and s.a <= 2 then + update set b = t.b || ' updated by merge' +when matched and s.a > 2 then + delete +when not matched then + insert values (a, b); +NOTICE: trigger = merge_target_table_delete_trig, old table = (3,initial3), (4,initial4) +NOTICE: trigger = merge_target_table_update_trig, old table = (1,initial1), (2,initial2), new table = (1,"initial1 updated by merge"), (2,"initial2 updated by merge") +NOTICE: trigger = merge_target_table_insert_trig, new table = +merge into merge_target_table t +using merge_source_table s +on t.a = s.a +when matched and s.a <= 2 then + update set b = t.b || ' updated again by merge' +when matched and s.a > 2 then + delete +when not matched then + insert values (a, b); +NOTICE: trigger = merge_target_table_delete_trig, old table = +NOTICE: trigger = merge_target_table_update_trig, old table = (1,"initial1 updated by merge"), (2,"initial2 updated by merge"), new table = (1,"initial1 updated by merge updated again by merge"), (2,"initial2 updated by merge updated again by merge") +NOTICE: trigger = merge_target_table_insert_trig, new table = (3,initial3), (4,initial4) +drop table merge_source_table, merge_target_table; -- cleanup drop function dump_insert(); drop function dump_update(); diff --git a/src/test/regress/expected/with.out b/src/test/regress/expected/with.out index ff76ad4d6e..7c6de7cc07 100644 --- a/src/test/regress/expected/with.out +++ b/src/test/regress/expected/with.out @@ -2767,6 +2767,139 @@ RETURNING k, v; (0 rows) DROP TABLE withz; +-- WITH referenced by MERGE statement +CREATE TABLE m AS SELECT i AS k, (i || ' v')::text v FROM generate_series(1, 16, 3) i; +ALTER TABLE m ADD UNIQUE (k); +WITH RECURSIVE cte_basic AS (SELECT 1 a, 'cte_basic val' b) +MERGE INTO m USING (select 0 k, 'merge source SubPlan' v) o ON m.k=o.k +WHEN MATCHED THEN UPDATE SET v = (SELECT b || ' merge update' FROM cte_basic WHERE cte_basic.a = m.k LIMIT 1) +WHEN NOT MATCHED THEN INSERT VALUES(o.k, o.v); +ERROR: WITH RECURSIVE is not supported for MERGE statement +-- Basic: +WITH cte_basic AS MATERIALIZED (SELECT 1 a, 'cte_basic val' b) +MERGE INTO m USING (select 0 k, 'merge source SubPlan' v offset 0) o ON m.k=o.k +WHEN MATCHED THEN UPDATE SET v = (SELECT b || ' merge update' FROM cte_basic WHERE cte_basic.a = m.k LIMIT 1) +WHEN NOT MATCHED THEN INSERT VALUES(o.k, o.v); +-- Examine +SELECT * FROM m where k = 0; + k | v +---+---------------------- + 0 | merge source SubPlan +(1 row) + +-- See EXPLAIN output for same query: +EXPLAIN (VERBOSE, COSTS OFF) +WITH cte_basic AS MATERIALIZED (SELECT 1 a, 'cte_basic val' b) +MERGE INTO m USING (select 0 k, 'merge source SubPlan' v offset 0) o ON m.k=o.k +WHEN MATCHED THEN UPDATE SET v = (SELECT b || ' merge update' FROM cte_basic WHERE cte_basic.a = m.k LIMIT 1) +WHEN NOT MATCHED THEN INSERT VALUES(o.k, o.v); + QUERY PLAN +---------------------------------------------------------------- + Merge on public.m + CTE cte_basic + -> Result + Output: 1, 'cte_basic val'::text + -> Hash Right Join + Output: (0), ('merge source SubPlan'::text), m.ctid + Hash Cond: (m.k = (0)) + -> Seq Scan on public.m + Output: m.ctid, m.k + -> Hash + Output: (0), ('merge source SubPlan'::text) + -> Result + Output: 0, 'merge source SubPlan'::text + SubPlan 2 + -> Limit + Output: ((cte_basic.b || ' merge update'::text)) + -> CTE Scan on cte_basic + Output: (cte_basic.b || ' merge update'::text) + Filter: (cte_basic.a = m.k) +(19 rows) + +-- InitPlan +WITH cte_init AS MATERIALIZED (SELECT 1 a, 'cte_init val' b) +MERGE INTO m USING (select 1 k, 'merge source InitPlan' v offset 0) o ON m.k=o.k +WHEN MATCHED THEN UPDATE SET v = (SELECT b || ' merge update' FROM cte_init WHERE a = 1 LIMIT 1) +WHEN NOT MATCHED THEN INSERT VALUES(o.k, o.v); +-- Examine +SELECT * FROM m where k = 1; + k | v +---+--------------------------- + 1 | cte_init val merge update +(1 row) + +-- See EXPLAIN output for same query: +EXPLAIN (VERBOSE, COSTS OFF) +WITH cte_init AS MATERIALIZED (SELECT 1 a, 'cte_init val' b) +MERGE INTO m USING (select 1 k, 'merge source InitPlan' v offset 0) o ON m.k=o.k +WHEN MATCHED THEN UPDATE SET v = (SELECT b || ' merge update' FROM cte_init WHERE a = 1 LIMIT 1) +WHEN NOT MATCHED THEN INSERT VALUES(o.k, o.v); + QUERY PLAN +--------------------------------------------------------------- + Merge on public.m + CTE cte_init + -> Result + Output: 1, 'cte_init val'::text + InitPlan 2 (returns $1) + -> Limit + Output: ((cte_init.b || ' merge update'::text)) + -> CTE Scan on cte_init + Output: (cte_init.b || ' merge update'::text) + Filter: (cte_init.a = 1) + -> Hash Right Join + Output: (1), ('merge source InitPlan'::text), m.ctid + Hash Cond: (m.k = (1)) + -> Seq Scan on public.m + Output: m.ctid, m.k + -> Hash + Output: (1), ('merge source InitPlan'::text) + -> Result + Output: 1, 'merge source InitPlan'::text +(19 rows) + +-- MERGE source comes from CTE: +WITH merge_source_cte AS MATERIALIZED (SELECT 15 a, 'merge_source_cte val' b) +MERGE INTO m USING (select * from merge_source_cte) o ON m.k=o.a +WHEN MATCHED THEN UPDATE SET v = (SELECT b || merge_source_cte.*::text || ' merge update' FROM merge_source_cte WHERE a = 15) +WHEN NOT MATCHED THEN INSERT VALUES(o.a, o.b || (SELECT merge_source_cte.*::text || ' merge insert' FROM merge_source_cte)); +-- Examine +SELECT * FROM m where k = 15; + k | v +----+-------------------------------------------------------------- + 15 | merge_source_cte val(15,"merge_source_cte val") merge insert +(1 row) + +-- See EXPLAIN output for same query: +EXPLAIN (VERBOSE, COSTS OFF) +WITH merge_source_cte AS MATERIALIZED (SELECT 15 a, 'merge_source_cte val' b) +MERGE INTO m USING (select * from merge_source_cte) o ON m.k=o.a +WHEN MATCHED THEN UPDATE SET v = (SELECT b || merge_source_cte.*::text || ' merge update' FROM merge_source_cte WHERE a = 15) +WHEN NOT MATCHED THEN INSERT VALUES(o.a, o.b || (SELECT merge_source_cte.*::text || ' merge insert' FROM merge_source_cte)); + QUERY PLAN +----------------------------------------------------------------------------------------------------- + Merge on public.m + CTE merge_source_cte + -> Result + Output: 15, 'merge_source_cte val'::text + InitPlan 2 (returns $1) + -> CTE Scan on merge_source_cte merge_source_cte_1 + Output: ((merge_source_cte_1.b || (merge_source_cte_1.*)::text) || ' merge update'::text) + Filter: (merge_source_cte_1.a = 15) + InitPlan 3 (returns $2) + -> CTE Scan on merge_source_cte merge_source_cte_2 + Output: ((merge_source_cte_2.*)::text || ' merge insert'::text) + -> Hash Right Join + Output: merge_source_cte.a, merge_source_cte.b, m.ctid + Hash Cond: (m.k = merge_source_cte.a) + -> Seq Scan on public.m + Output: m.ctid, m.k + -> Hash + Output: merge_source_cte.a, merge_source_cte.b + -> CTE Scan on merge_source_cte + Output: merge_source_cte.a, merge_source_cte.b +(20 rows) + +DROP TABLE m; -- check that run to completion happens in proper ordering TRUNCATE TABLE y; INSERT INTO y SELECT generate_series(1, 3); diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule index 3ce701a588..58fab1de1a 100644 --- a/src/test/regress/parallel_schedule +++ b/src/test/regress/parallel_schedule @@ -86,7 +86,7 @@ test: brin_bloom brin_multi # psql depends on create_am # amutils depends on geometry, create_index_spgist, hash_index, brin # ---------- -test: create_table_like alter_generic alter_operator misc async dbsize misc_functions sysviews tsrf tid tidscan tidrangescan collate.icu.utf8 incremental_sort create_role +test: create_table_like alter_generic alter_operator misc async dbsize merge misc_functions sysviews tsrf tid tidscan tidrangescan collate.icu.utf8 incremental_sort create_role # collate.*.utf8 tests cannot be run in parallel with each other test: rules psql psql_crosstab amutils stats_ext collate.linux.utf8 diff --git a/src/test/regress/sql/identity.sql b/src/test/regress/sql/identity.sql index 52800f265c..9b8db2e4a3 100644 --- a/src/test/regress/sql/identity.sql +++ b/src/test/regress/sql/identity.sql @@ -355,3 +355,49 @@ CREATE TABLE itest15 (id integer GENERATED ALWAYS AS IDENTITY NOT NULL); DROP TABLE itest15; CREATE TABLE itest15 (id integer NOT NULL GENERATED ALWAYS AS IDENTITY); DROP TABLE itest15; + +-- MERGE tests +CREATE TABLE itest15 (a int GENERATED ALWAYS AS IDENTITY, b text); +CREATE TABLE itest16 (a int GENERATED BY DEFAULT AS IDENTITY, b text); + +MERGE INTO itest15 t +USING (SELECT 10 AS s_a, 'inserted by merge' AS s_b) s +ON t.a = s.s_a +WHEN NOT MATCHED THEN + INSERT (a, b) VALUES (s.s_a, s.s_b); + +-- Used to fail, but now it works and ignores the user supplied value +MERGE INTO itest15 t +USING (SELECT 20 AS s_a, 'inserted by merge' AS s_b) s +ON t.a = s.s_a +WHEN NOT MATCHED THEN + INSERT (a, b) OVERRIDING USER VALUE VALUES (s.s_a, s.s_b); + +MERGE INTO itest15 t +USING (SELECT 30 AS s_a, 'inserted by merge' AS s_b) s +ON t.a = s.s_a +WHEN NOT MATCHED THEN + INSERT (a, b) OVERRIDING SYSTEM VALUE VALUES (s.s_a, s.s_b); + +MERGE INTO itest16 t +USING (SELECT 10 AS s_a, 'inserted by merge' AS s_b) s +ON t.a = s.s_a +WHEN NOT MATCHED THEN + INSERT (a, b) VALUES (s.s_a, s.s_b); + +MERGE INTO itest16 t +USING (SELECT 20 AS s_a, 'inserted by merge' AS s_b) s +ON t.a = s.s_a +WHEN NOT MATCHED THEN + INSERT (a, b) OVERRIDING USER VALUE VALUES (s.s_a, s.s_b); + +MERGE INTO itest16 t +USING (SELECT 30 AS s_a, 'inserted by merge' AS s_b) s +ON t.a = s.s_a +WHEN NOT MATCHED THEN + INSERT (a, b) OVERRIDING SYSTEM VALUE VALUES (s.s_a, s.s_b); + +SELECT * FROM itest15; +SELECT * FROM itest16; +DROP TABLE itest15; +DROP TABLE itest16; diff --git a/src/test/regress/sql/merge.sql b/src/test/regress/sql/merge.sql new file mode 100644 index 0000000000..34282e0794 --- /dev/null +++ b/src/test/regress/sql/merge.sql @@ -0,0 +1,1273 @@ +-- +-- MERGE +-- +--\set VERBOSITY verbose + +--set debug_print_rewritten = true; +--set debug_print_parse = true; +--set debug_print_pretty = true; + + +CREATE USER merge_privs; +CREATE USER merge_no_privs; +DROP TABLE IF EXISTS target; +DROP TABLE IF EXISTS source; +CREATE TABLE target (tid integer, balance integer); +CREATE TABLE source (sid integer, delta integer); --no index +INSERT INTO target VALUES (1, 10); +INSERT INTO target VALUES (2, 20); +INSERT INTO target VALUES (3, 30); +SELECT t.ctid is not null as matched, t.*, s.* FROM source s FULL OUTER JOIN target t ON s.sid = t.tid ORDER BY t.tid, s.sid; + +ALTER TABLE target OWNER TO merge_privs; +ALTER TABLE source OWNER TO merge_privs; + +CREATE TABLE target2 (tid integer, balance integer); +CREATE TABLE source2 (sid integer, delta integer); + +ALTER TABLE target2 OWNER TO merge_no_privs; +ALTER TABLE source2 OWNER TO merge_no_privs; + +GRANT INSERT ON target TO merge_no_privs; + +SET SESSION AUTHORIZATION merge_privs; + +EXPLAIN (COSTS OFF) +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN MATCHED THEN + DELETE; + +-- +-- Errors +-- +MERGE INTO target t RANDOMWORD +USING source AS s +ON t.tid = s.sid +WHEN MATCHED THEN + UPDATE SET balance = 0; +-- MATCHED/INSERT error +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN MATCHED THEN + INSERT DEFAULT VALUES; +-- incorrectly specifying INTO target +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN NOT MATCHED THEN + INSERT INTO target DEFAULT VALUES; +-- Multiple VALUES clause +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN NOT MATCHED THEN + INSERT VALUES (1,1), (2,2); +-- SELECT query for INSERT +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN NOT MATCHED THEN + INSERT SELECT (1, 1); +-- NOT MATCHED/UPDATE +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN NOT MATCHED THEN + UPDATE SET balance = 0; +-- UPDATE tablename +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN MATCHED THEN + UPDATE target SET balance = 0; +-- source and target names the same +MERGE INTO target +USING target +ON tid = tid +WHEN MATCHED THEN DO NOTHING; + +-- unsupported relation types +-- view +CREATE VIEW tv AS SELECT * FROM target; +MERGE INTO tv t +USING source s +ON t.tid = s.sid +WHEN NOT MATCHED THEN + INSERT DEFAULT VALUES; +DROP VIEW tv; + +-- materialized view +CREATE MATERIALIZED VIEW mv AS SELECT * FROM target; +MERGE INTO mv t +USING source s +ON t.tid = s.sid +WHEN NOT MATCHED THEN + INSERT DEFAULT VALUES; +DROP MATERIALIZED VIEW mv; + +-- permissions + +MERGE INTO target +USING source2 +ON target.tid = source2.sid +WHEN MATCHED THEN + UPDATE SET balance = 0; + +GRANT INSERT ON target TO merge_no_privs; +SET SESSION AUTHORIZATION merge_no_privs; + +MERGE INTO target +USING source2 +ON target.tid = source2.sid +WHEN MATCHED THEN + UPDATE SET balance = 0; + +GRANT UPDATE ON target2 TO merge_privs; +SET SESSION AUTHORIZATION merge_privs; + +MERGE INTO target2 +USING source +ON target2.tid = source.sid +WHEN MATCHED THEN + DELETE; + +MERGE INTO target2 +USING source +ON target2.tid = source.sid +WHEN NOT MATCHED THEN + INSERT DEFAULT VALUES; + +-- check if the target can be accessed from source relation subquery; we should +-- not be able to do so +MERGE INTO target t +USING (SELECT * FROM source WHERE t.tid > sid) s +ON t.tid = s.sid +WHEN NOT MATCHED THEN + INSERT DEFAULT VALUES; + +-- +-- initial tests +-- +-- zero rows in source has no effect +MERGE INTO target +USING source +ON target.tid = source.sid +WHEN MATCHED THEN + UPDATE SET balance = 0; + +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN MATCHED THEN + UPDATE SET balance = 0; +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN MATCHED THEN + DELETE; +BEGIN; +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN NOT MATCHED THEN + INSERT DEFAULT VALUES; +ROLLBACK; + +-- insert some non-matching source rows to work from +INSERT INTO source VALUES (4, 40); +SELECT * FROM source ORDER BY sid; +SELECT * FROM target ORDER BY tid; + +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN NOT MATCHED THEN + DO NOTHING; +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN MATCHED THEN + UPDATE SET balance = 0; +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN MATCHED THEN + DELETE; +BEGIN; +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN NOT MATCHED THEN + INSERT DEFAULT VALUES; +SELECT * FROM target ORDER BY tid; +ROLLBACK; + +-- index plans +INSERT INTO target SELECT generate_series(1000,2500), 0; +ALTER TABLE target ADD PRIMARY KEY (tid); +ANALYZE target; + +EXPLAIN (COSTS OFF) +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN MATCHED THEN + UPDATE SET balance = 0; +EXPLAIN (COSTS OFF) +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN MATCHED THEN + DELETE; +EXPLAIN (COSTS OFF) +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN NOT MATCHED THEN + INSERT VALUES (4, NULL); +DELETE FROM target WHERE tid > 100; +ANALYZE target; + +-- insert some matching source rows to work from +INSERT INTO source VALUES (2, 5); +INSERT INTO source VALUES (3, 20); +SELECT * FROM source ORDER BY sid; +SELECT * FROM target ORDER BY tid; + +-- equivalent of an UPDATE join +BEGIN; +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN MATCHED THEN + UPDATE SET balance = 0; +SELECT * FROM target ORDER BY tid; +ROLLBACK; + +-- equivalent of a DELETE join +BEGIN; +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN MATCHED THEN + DELETE; +SELECT * FROM target ORDER BY tid; +ROLLBACK; + +BEGIN; +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN MATCHED THEN + DO NOTHING; +SELECT * FROM target ORDER BY tid; +ROLLBACK; + +BEGIN; +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN NOT MATCHED THEN + INSERT VALUES (4, NULL); +SELECT * FROM target ORDER BY tid; +ROLLBACK; + +-- duplicate source row causes multiple target row update ERROR +INSERT INTO source VALUES (2, 5); +SELECT * FROM source ORDER BY sid; +SELECT * FROM target ORDER BY tid; +BEGIN; +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN MATCHED THEN + UPDATE SET balance = 0; +ROLLBACK; + +BEGIN; +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN MATCHED THEN + DELETE; +ROLLBACK; + +-- remove duplicate MATCHED data from source data +DELETE FROM source WHERE sid = 2; +INSERT INTO source VALUES (2, 5); +SELECT * FROM source ORDER BY sid; +SELECT * FROM target ORDER BY tid; + +-- duplicate source row on INSERT should fail because of target_pkey +INSERT INTO source VALUES (4, 40); +BEGIN; +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN NOT MATCHED THEN + INSERT VALUES (4, NULL); +SELECT * FROM target ORDER BY tid; +ROLLBACK; + +-- remove duplicate NOT MATCHED data from source data +DELETE FROM source WHERE sid = 4; +INSERT INTO source VALUES (4, 40); +SELECT * FROM source ORDER BY sid; +SELECT * FROM target ORDER BY tid; + +-- remove constraints +alter table target drop CONSTRAINT target_pkey; +alter table target alter column tid drop not null; + +-- multiple actions +BEGIN; +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN NOT MATCHED THEN + INSERT VALUES (4, 4) +WHEN MATCHED THEN + UPDATE SET balance = 0; +SELECT * FROM target ORDER BY tid; +ROLLBACK; + +-- should be equivalent +BEGIN; +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN MATCHED THEN + UPDATE SET balance = 0 +WHEN NOT MATCHED THEN + INSERT VALUES (4, 4); +SELECT * FROM target ORDER BY tid; +ROLLBACK; + +-- column references +-- do a simple equivalent of an UPDATE join +BEGIN; +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN MATCHED THEN + UPDATE SET balance = t.balance + s.delta; +SELECT * FROM target ORDER BY tid; +ROLLBACK; + +-- do a simple equivalent of an INSERT SELECT +BEGIN; +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN NOT MATCHED THEN + INSERT VALUES (s.sid, s.delta); +SELECT * FROM target ORDER BY tid; +ROLLBACK; + +-- and again with duplicate source rows +INSERT INTO source VALUES (5, 50); +INSERT INTO source VALUES (5, 50); + +-- do a simple equivalent of an INSERT SELECT +BEGIN; +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN NOT MATCHED THEN + INSERT VALUES (s.sid, s.delta); +SELECT * FROM target ORDER BY tid; +ROLLBACK; + +-- removing duplicate source rows +DELETE FROM source WHERE sid = 5; + +-- and again with explicitly identified column list +BEGIN; +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN NOT MATCHED THEN + INSERT (tid, balance) VALUES (s.sid, s.delta); +SELECT * FROM target ORDER BY tid; +ROLLBACK; + +-- and again with a subtle error: referring to non-existent target row for NOT MATCHED +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN NOT MATCHED THEN + INSERT (tid, balance) VALUES (t.tid, s.delta); + +-- and again with a constant ON clause +BEGIN; +MERGE INTO target t +USING source AS s +ON (SELECT true) +WHEN NOT MATCHED THEN + INSERT (tid, balance) VALUES (t.tid, s.delta); +SELECT * FROM target ORDER BY tid; +ROLLBACK; + +-- now the classic UPSERT +BEGIN; +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN MATCHED THEN + UPDATE SET balance = t.balance + s.delta +WHEN NOT MATCHED THEN + INSERT VALUES (s.sid, s.delta); +SELECT * FROM target ORDER BY tid; +ROLLBACK; + +-- unreachable WHEN clause should ERROR +BEGIN; +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN MATCHED THEN /* Terminal WHEN clause for MATCHED */ + DELETE +WHEN MATCHED AND s.delta > 0 THEN + UPDATE SET balance = t.balance - s.delta; +ROLLBACK; + +-- conditional WHEN clause +CREATE TABLE wq_target (tid integer not null, balance integer DEFAULT -1); +CREATE TABLE wq_source (balance integer, sid integer); + +INSERT INTO wq_source (sid, balance) VALUES (1, 100); + +BEGIN; +-- try a simple INSERT with default values first +MERGE INTO wq_target t +USING wq_source s ON t.tid = s.sid +WHEN NOT MATCHED THEN + INSERT (tid) VALUES (s.sid); +SELECT * FROM wq_target; +ROLLBACK; + +-- this time with a FALSE condition +MERGE INTO wq_target t +USING wq_source s ON t.tid = s.sid +WHEN NOT MATCHED AND FALSE THEN + INSERT (tid) VALUES (s.sid); +SELECT * FROM wq_target; + +-- this time with an actual condition which returns false +MERGE INTO wq_target t +USING wq_source s ON t.tid = s.sid +WHEN NOT MATCHED AND s.balance <> 100 THEN + INSERT (tid) VALUES (s.sid); +SELECT * FROM wq_target; + +BEGIN; +-- and now with a condition which returns true +MERGE INTO wq_target t +USING wq_source s ON t.tid = s.sid +WHEN NOT MATCHED AND s.balance = 100 THEN + INSERT (tid) VALUES (s.sid); +SELECT * FROM wq_target; +ROLLBACK; + +-- conditions in the NOT MATCHED clause can only refer to source columns +BEGIN; +MERGE INTO wq_target t +USING wq_source s ON t.tid = s.sid +WHEN NOT MATCHED AND t.balance = 100 THEN + INSERT (tid) VALUES (s.sid); +SELECT * FROM wq_target; +ROLLBACK; + +MERGE INTO wq_target t +USING wq_source s ON t.tid = s.sid +WHEN NOT MATCHED AND s.balance = 100 THEN + INSERT (tid) VALUES (s.sid); +SELECT * FROM wq_target; + +-- conditions in MATCHED clause can refer to both source and target +SELECT * FROM wq_source; +MERGE INTO wq_target t +USING wq_source s ON t.tid = s.sid +WHEN MATCHED AND s.balance = 100 THEN + UPDATE SET balance = t.balance + s.balance; +SELECT * FROM wq_target; + +MERGE INTO wq_target t +USING wq_source s ON t.tid = s.sid +WHEN MATCHED AND t.balance = 100 THEN + UPDATE SET balance = t.balance + s.balance; +SELECT * FROM wq_target; + +-- check if AND works +MERGE INTO wq_target t +USING wq_source s ON t.tid = s.sid +WHEN MATCHED AND t.balance = 99 AND s.balance > 100 THEN + UPDATE SET balance = t.balance + s.balance; +SELECT * FROM wq_target; + +MERGE INTO wq_target t +USING wq_source s ON t.tid = s.sid +WHEN MATCHED AND t.balance = 99 AND s.balance = 100 THEN + UPDATE SET balance = t.balance + s.balance; +SELECT * FROM wq_target; + +-- check if OR works +MERGE INTO wq_target t +USING wq_source s ON t.tid = s.sid +WHEN MATCHED AND t.balance = 99 OR s.balance > 100 THEN + UPDATE SET balance = t.balance + s.balance; +SELECT * FROM wq_target; + +MERGE INTO wq_target t +USING wq_source s ON t.tid = s.sid +WHEN MATCHED AND t.balance = 199 OR s.balance > 100 THEN + UPDATE SET balance = t.balance + s.balance; +SELECT * FROM wq_target; + +-- check if subqueries work in the conditions? +MERGE INTO wq_target t +USING wq_source s ON t.tid = s.sid +WHEN MATCHED AND t.balance > (SELECT max(balance) FROM target) THEN + UPDATE SET balance = t.balance + s.balance; + +-- check if we can access system columns in the conditions +MERGE INTO wq_target t +USING wq_source s ON t.tid = s.sid +WHEN MATCHED AND t.xmin = t.xmax THEN + UPDATE SET balance = t.balance + s.balance; + +MERGE INTO wq_target t +USING wq_source s ON t.tid = s.sid +WHEN MATCHED AND t.tableoid >= 0 THEN + UPDATE SET balance = t.balance + s.balance; +SELECT * FROM wq_target; + +-- test preventing WHEN conditions from writing to the database +create or replace function merge_when_and_write() returns boolean +language plpgsql as +$$ +BEGIN + INSERT INTO target VALUES (100, 100); + RETURN TRUE; +END; +$$; + +BEGIN; +MERGE INTO wq_target t +USING wq_source s ON t.tid = s.sid +WHEN MATCHED AND (merge_when_and_write()) THEN + UPDATE SET balance = t.balance + s.balance; +ROLLBACK; +drop function merge_when_and_write(); + +DROP TABLE wq_target, wq_source; + +-- test triggers +create or replace function merge_trigfunc () returns trigger +language plpgsql as +$$ +DECLARE + line text; +BEGIN + SELECT INTO line format('%s %s %s trigger%s', + TG_WHEN, TG_OP, TG_LEVEL, CASE + WHEN TG_OP = 'INSERT' AND TG_LEVEL = 'ROW' + THEN format(' row: %s', NEW) + WHEN TG_OP = 'UPDATE' AND TG_LEVEL = 'ROW' + THEN format(' row: %s -> %s', OLD, NEW) + WHEN TG_OP = 'DELETE' AND TG_LEVEL = 'ROW' + THEN format(' row: %s', OLD) + END); + + RAISE NOTICE '%', line; + IF (TG_WHEN = 'BEFORE' AND TG_LEVEL = 'ROW') THEN + IF (TG_OP = 'DELETE') THEN + RETURN OLD; + ELSE + RETURN NEW; + END IF; + ELSE + RETURN NULL; + END IF; +END; +$$; +CREATE TRIGGER merge_bsi BEFORE INSERT ON target FOR EACH STATEMENT EXECUTE PROCEDURE merge_trigfunc (); +CREATE TRIGGER merge_bsu BEFORE UPDATE ON target FOR EACH STATEMENT EXECUTE PROCEDURE merge_trigfunc (); +CREATE TRIGGER merge_bsd BEFORE DELETE ON target FOR EACH STATEMENT EXECUTE PROCEDURE merge_trigfunc (); +CREATE TRIGGER merge_asi AFTER INSERT ON target FOR EACH STATEMENT EXECUTE PROCEDURE merge_trigfunc (); +CREATE TRIGGER merge_asu AFTER UPDATE ON target FOR EACH STATEMENT EXECUTE PROCEDURE merge_trigfunc (); +CREATE TRIGGER merge_asd AFTER DELETE ON target FOR EACH STATEMENT EXECUTE PROCEDURE merge_trigfunc (); +CREATE TRIGGER merge_bri BEFORE INSERT ON target FOR EACH ROW EXECUTE PROCEDURE merge_trigfunc (); +CREATE TRIGGER merge_bru BEFORE UPDATE ON target FOR EACH ROW EXECUTE PROCEDURE merge_trigfunc (); +CREATE TRIGGER merge_brd BEFORE DELETE ON target FOR EACH ROW EXECUTE PROCEDURE merge_trigfunc (); +CREATE TRIGGER merge_ari AFTER INSERT ON target FOR EACH ROW EXECUTE PROCEDURE merge_trigfunc (); +CREATE TRIGGER merge_aru AFTER UPDATE ON target FOR EACH ROW EXECUTE PROCEDURE merge_trigfunc (); +CREATE TRIGGER merge_ard AFTER DELETE ON target FOR EACH ROW EXECUTE PROCEDURE merge_trigfunc (); + +-- now the classic UPSERT, with a DELETE +BEGIN; +UPDATE target SET balance = 0 WHERE tid = 3; +--EXPLAIN (ANALYZE ON, COSTS OFF, SUMMARY OFF, TIMING OFF) +MERGE INTO target 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 THEN + INSERT VALUES (s.sid, s.delta); +SELECT * FROM target ORDER BY tid; +ROLLBACK; + +-- Test behavior of triggers that turn UPDATE/DELETE into no-ops +create or replace function skip_merge_op() returns trigger +language plpgsql as +$$ +BEGIN + RETURN NULL; +END; +$$; + +SELECT * FROM target full outer join source on (sid = tid); +create trigger merge_skip BEFORE INSERT OR UPDATE or DELETE + ON target FOR EACH ROW EXECUTE FUNCTION skip_merge_op(); +MERGE INTO target t +USING source AS s +ON t.tid = s.sid +WHEN MATCHED AND s.sid = 3 THEN UPDATE SET balance = t.balance + s.delta +WHEN MATCHED THEN DELETE +WHEN NOT MATCHED THEN INSERT VALUES (sid, delta); +SELECT * FROM target FULL OUTER JOIN source ON (sid = tid); +DROP TRIGGER merge_skip ON target; +DROP FUNCTION skip_merge_op(); + +-- test from PL/pgSQL +-- make sure MERGE INTO isn't interpreted to mean returning variables like SELECT INTO +BEGIN; +DO LANGUAGE plpgsql $$ +BEGIN +MERGE INTO target 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; +END; +$$; +ROLLBACK; + +--source constants +BEGIN; +MERGE INTO target t +USING (SELECT 9 AS sid, 57 AS delta) AS s +ON t.tid = s.sid +WHEN NOT MATCHED THEN + INSERT (tid, balance) VALUES (s.sid, s.delta); +SELECT * FROM target ORDER BY tid; +ROLLBACK; + +--source query +BEGIN; +MERGE INTO target t +USING (SELECT sid, delta FROM source WHERE delta > 0) AS s +ON t.tid = s.sid +WHEN NOT MATCHED THEN + INSERT (tid, balance) VALUES (s.sid, s.delta); +SELECT * FROM target ORDER BY tid; +ROLLBACK; + +BEGIN; +MERGE INTO target t +USING (SELECT sid, delta as newname FROM source WHERE delta > 0) AS s +ON t.tid = s.sid +WHEN NOT MATCHED THEN + INSERT (tid, balance) VALUES (s.sid, s.newname); +SELECT * FROM target ORDER BY tid; +ROLLBACK; + +--self-merge +BEGIN; +MERGE INTO target t1 +USING target t2 +ON t1.tid = t2.tid +WHEN MATCHED THEN + UPDATE SET balance = t1.balance + t2.balance +WHEN NOT MATCHED THEN + INSERT VALUES (t2.tid, t2.balance); +SELECT * FROM target ORDER BY tid; +ROLLBACK; + +BEGIN; +MERGE INTO target t +USING (SELECT tid as sid, balance as delta FROM target WHERE balance > 0) AS s +ON t.tid = s.sid +WHEN NOT MATCHED THEN + INSERT (tid, balance) VALUES (s.sid, s.delta); +SELECT * FROM target ORDER BY tid; +ROLLBACK; + +BEGIN; +MERGE INTO target t +USING +(SELECT sid, max(delta) AS delta + FROM source + GROUP BY sid + HAVING count(*) = 1 + ORDER BY sid ASC) AS s +ON t.tid = s.sid +WHEN NOT MATCHED THEN + INSERT (tid, balance) VALUES (s.sid, s.delta); +SELECT * FROM target ORDER BY tid; +ROLLBACK; + +-- plpgsql parameters and results +BEGIN; +CREATE FUNCTION merge_func (p_id integer, p_bal integer) +RETURNS INTEGER +LANGUAGE plpgsql +AS $$ +DECLARE + result integer; +BEGIN +MERGE INTO target t +USING (SELECT p_id AS sid) AS s +ON t.tid = s.sid +WHEN MATCHED THEN + UPDATE SET balance = t.balance - p_bal; +IF FOUND THEN + GET DIAGNOSTICS result := ROW_COUNT; +END IF; +RETURN result; +END; +$$; +SELECT merge_func(3, 4); +SELECT * FROM target ORDER BY tid; +ROLLBACK; + +-- PREPARE +BEGIN; +prepare foom as merge into target t using (select 1 as sid) s on (t.tid = s.sid) when matched then update set balance = 1; +execute foom; +SELECT * FROM target ORDER BY tid; +ROLLBACK; + +BEGIN; +PREPARE foom2 (integer, integer) AS +MERGE INTO target t +USING (SELECT 1) s +ON t.tid = $1 +WHEN MATCHED THEN +UPDATE SET balance = $2; +--EXPLAIN (ANALYZE ON, COSTS OFF, SUMMARY OFF, TIMING OFF) +execute foom2 (1, 1); +SELECT * FROM target ORDER BY tid; +ROLLBACK; + +-- subqueries in source relation + +CREATE TABLE sq_target (tid integer NOT NULL, balance integer); +CREATE TABLE sq_source (delta integer, sid integer, balance integer DEFAULT 0); + +INSERT INTO sq_target(tid, balance) VALUES (1,100), (2,200), (3,300); +INSERT INTO sq_source(sid, delta) VALUES (1,10), (2,20), (4,40); + +BEGIN; +MERGE INTO sq_target t +USING (SELECT * FROM sq_source) s +ON tid = sid +WHEN MATCHED AND t.balance > delta THEN + UPDATE SET balance = t.balance + delta; +SELECT * FROM sq_target; +ROLLBACK; + +-- try a view +CREATE VIEW v AS SELECT * FROM sq_source WHERE sid < 2; + +BEGIN; +MERGE INTO sq_target +USING v +ON tid = sid +WHEN MATCHED THEN + UPDATE SET balance = v.balance + delta; +SELECT * FROM sq_target; +ROLLBACK; + +-- ambiguous reference to a column +BEGIN; +MERGE INTO sq_target +USING v +ON tid = sid +WHEN MATCHED AND tid > 2 THEN + UPDATE SET balance = balance + delta +WHEN NOT MATCHED THEN + INSERT (balance, tid) VALUES (balance + delta, sid) +WHEN MATCHED AND tid < 2 THEN + DELETE; +ROLLBACK; + +BEGIN; +INSERT INTO sq_source (sid, balance, delta) VALUES (-1, -1, -10); +MERGE INTO sq_target t +USING v +ON tid = sid +WHEN MATCHED AND tid > 2 THEN + UPDATE SET balance = t.balance + delta +WHEN NOT MATCHED THEN + INSERT (balance, tid) VALUES (balance + delta, sid) +WHEN MATCHED AND tid < 2 THEN + DELETE; +SELECT * FROM sq_target; +ROLLBACK; + +-- CTEs +BEGIN; +INSERT INTO sq_source (sid, balance, delta) VALUES (-1, -1, -10); +WITH targq AS ( + SELECT * FROM v +) +MERGE INTO sq_target t +USING v +ON tid = sid +WHEN MATCHED AND tid > 2 THEN + UPDATE SET balance = t.balance + delta +WHEN NOT MATCHED THEN + INSERT (balance, tid) VALUES (balance + delta, sid) +WHEN MATCHED AND tid < 2 THEN + DELETE; +ROLLBACK; + +-- RETURNING +BEGIN; +INSERT INTO sq_source (sid, balance, delta) VALUES (-1, -1, -10); +MERGE INTO sq_target t +USING v +ON tid = sid +WHEN MATCHED AND tid > 2 THEN + UPDATE SET balance = t.balance + delta +WHEN NOT MATCHED THEN + INSERT (balance, tid) VALUES (balance + delta, sid) +WHEN MATCHED AND tid < 2 THEN + DELETE +RETURNING *; +ROLLBACK; + +-- EXPLAIN +CREATE TABLE ex_mtarget (a int, b int); +CREATE TABLE ex_msource (a int, b int); +INSERT INTO ex_mtarget SELECT i, i*10 FROM generate_series(1,100,2) i; +INSERT INTO ex_msource SELECT i, i*10 FROM generate_series(1,100,1) i; + +CREATE FUNCTION explain_merge(query text) RETURNS SETOF text +LANGUAGE plpgsql AS +$$ +DECLARE ln text; +BEGIN + FOR ln IN + EXECUTE 'explain (analyze, timing off, summary off, costs off) ' || + query + LOOP + ln := regexp_replace(ln, 'Memory: \S*', 'Memory: xxx'); + RETURN NEXT ln; + END LOOP; +END; +$$; + +-- only updates +SELECT explain_merge(' +MERGE INTO ex_mtarget t USING ex_msource s ON t.a = s.a +WHEN MATCHED THEN + UPDATE SET b = t.b + 1'); + +-- only updates to selected tuples +SELECT explain_merge(' +MERGE INTO ex_mtarget t USING ex_msource s ON t.a = s.a +WHEN MATCHED AND t.a < 10 THEN + UPDATE SET b = t.b + 1'); + +-- updates + deletes +SELECT explain_merge(' +MERGE INTO ex_mtarget t USING ex_msource s ON t.a = s.a +WHEN MATCHED AND t.a < 10 THEN + UPDATE SET b = t.b + 1 +WHEN MATCHED AND t.a >= 10 AND t.a <= 20 THEN + DELETE'); + +-- only inserts +SELECT explain_merge(' +MERGE INTO ex_mtarget t USING ex_msource s ON t.a = s.a +WHEN NOT MATCHED AND s.a < 10 THEN + INSERT VALUES (a, b)'); + +-- all three +SELECT explain_merge(' +MERGE INTO ex_mtarget t USING ex_msource s ON t.a = s.a +WHEN MATCHED AND t.a < 10 THEN + UPDATE SET b = t.b + 1 +WHEN MATCHED AND t.a >= 30 AND t.a <= 40 THEN + DELETE +WHEN NOT MATCHED AND s.a < 20 THEN + INSERT VALUES (a, b)'); + +DROP TABLE ex_msource, ex_mtarget; +DROP FUNCTION explain_merge(text); + +-- Subqueries +BEGIN; +MERGE INTO sq_target t +USING v +ON tid = sid +WHEN MATCHED THEN + UPDATE SET balance = (SELECT count(*) FROM sq_target); +SELECT * FROM sq_target WHERE tid = 1; +ROLLBACK; + +BEGIN; +MERGE INTO sq_target t +USING v +ON tid = sid +WHEN MATCHED AND (SELECT count(*) > 0 FROM sq_target) THEN + UPDATE SET balance = 42; +SELECT * FROM sq_target WHERE tid = 1; +ROLLBACK; + +BEGIN; +MERGE INTO sq_target t +USING v +ON tid = sid AND (SELECT count(*) > 0 FROM sq_target) +WHEN MATCHED THEN + UPDATE SET balance = 42; +SELECT * FROM sq_target WHERE tid = 1; +ROLLBACK; + +DROP TABLE sq_target, sq_source CASCADE; + +CREATE TABLE pa_target (tid integer, balance float, val text) + PARTITION BY LIST (tid); + +CREATE TABLE part1 PARTITION OF pa_target FOR VALUES IN (1,4); +CREATE TABLE part2 PARTITION OF pa_target FOR VALUES IN (2,5,6); +CREATE TABLE part3 PARTITION OF pa_target FOR VALUES IN (3,8,9); +CREATE TABLE part4 PARTITION OF pa_target DEFAULT; + +CREATE TABLE pa_source (sid integer, delta float); +-- insert many rows to the source table +INSERT INTO pa_source SELECT id, id * 10 FROM generate_series(1,14) AS id; +-- insert a few rows in the target table (odd numbered tid) +INSERT INTO pa_target SELECT id, id * 100, 'initial' FROM generate_series(1,14,2) AS id; + +-- try simple MERGE +BEGIN; +MERGE INTO pa_target t + USING pa_source s + ON t.tid = s.sid + WHEN MATCHED THEN + UPDATE SET balance = balance + delta, val = val || ' updated by merge' + WHEN NOT MATCHED THEN + INSERT VALUES (sid, delta, 'inserted by merge'); +SELECT * FROM pa_target ORDER BY tid; +ROLLBACK; + +-- same with a constant qual +BEGIN; +MERGE INTO pa_target t + USING pa_source s + ON t.tid = s.sid AND tid = 1 + WHEN MATCHED THEN + UPDATE SET balance = balance + delta, val = val || ' updated by merge' + WHEN NOT MATCHED THEN + INSERT VALUES (sid, delta, 'inserted by merge'); +SELECT * FROM pa_target ORDER BY tid; +ROLLBACK; + +-- try updating the partition key column +BEGIN; +MERGE INTO pa_target t + USING pa_source s + ON t.tid = s.sid + WHEN MATCHED THEN + UPDATE SET tid = tid + 1, balance = balance + delta, val = val || ' updated by merge' + WHEN NOT MATCHED THEN + INSERT VALUES (sid, delta, 'inserted by merge'); +SELECT * FROM pa_target ORDER BY tid; +ROLLBACK; + +DROP TABLE pa_target CASCADE; + +-- The target table is partitioned in the same way, but this time by attaching +-- partitions which have columns in different order, dropped columns etc. +CREATE TABLE pa_target (tid integer, balance float, val text) + PARTITION BY LIST (tid); + +CREATE TABLE part1 (tid integer, balance float, val text); +CREATE TABLE part2 (balance float, tid integer, val text); +CREATE TABLE part3 (tid integer, balance float, val text); +CREATE TABLE part4 (extraid text, tid integer, balance float, val text); +ALTER TABLE part4 DROP COLUMN extraid; + +ALTER TABLE pa_target ATTACH PARTITION part1 FOR VALUES IN (1,4); +ALTER TABLE pa_target ATTACH PARTITION part2 FOR VALUES IN (2,5,6); +ALTER TABLE pa_target ATTACH PARTITION part3 FOR VALUES IN (3,8,9); +ALTER TABLE pa_target ATTACH PARTITION part4 DEFAULT; + +-- insert a few rows in the target table (odd numbered tid) +INSERT INTO pa_target SELECT id, id * 100, 'initial' FROM generate_series(1,14,2) AS id; + +-- try simple MERGE +BEGIN; +MERGE INTO pa_target t + USING pa_source s + ON t.tid = s.sid + WHEN MATCHED THEN + UPDATE SET balance = balance + delta, val = val || ' updated by merge' + WHEN NOT MATCHED THEN + INSERT VALUES (sid, delta, 'inserted by merge'); +SELECT * FROM pa_target ORDER BY tid; +ROLLBACK; + +-- same with a constant qual +BEGIN; +MERGE INTO pa_target t + USING pa_source s + ON t.tid = s.sid AND tid IN (1, 5) + WHEN MATCHED AND tid % 5 = 0 THEN DELETE + WHEN MATCHED THEN + UPDATE SET balance = balance + delta, val = val || ' updated by merge' + WHEN NOT MATCHED THEN + INSERT VALUES (sid, delta, 'inserted by merge'); +SELECT * FROM pa_target ORDER BY tid; +ROLLBACK; + +-- try updating the partition key column +BEGIN; +MERGE INTO pa_target t + USING pa_source s + ON t.tid = s.sid + WHEN MATCHED THEN + UPDATE SET tid = tid + 1, balance = balance + delta, val = val || ' updated by merge' + WHEN NOT MATCHED THEN + INSERT VALUES (sid, delta, 'inserted by merge'); +SELECT * FROM pa_target ORDER BY tid; +ROLLBACK; + +DROP TABLE pa_source; +DROP TABLE pa_target CASCADE; + +-- Sub-partitioning +CREATE TABLE pa_target (logts timestamp, tid integer, balance float, val text) + PARTITION BY RANGE (logts); + +CREATE TABLE part_m01 PARTITION OF pa_target + FOR VALUES FROM ('2017-01-01') TO ('2017-02-01') + PARTITION BY LIST (tid); +CREATE TABLE part_m01_odd PARTITION OF part_m01 + FOR VALUES IN (1,3,5,7,9); +CREATE TABLE part_m01_even PARTITION OF part_m01 + FOR VALUES IN (2,4,6,8); +CREATE TABLE part_m02 PARTITION OF pa_target + FOR VALUES FROM ('2017-02-01') TO ('2017-03-01') + PARTITION BY LIST (tid); +CREATE TABLE part_m02_odd PARTITION OF part_m02 + FOR VALUES IN (1,3,5,7,9); +CREATE TABLE part_m02_even PARTITION OF part_m02 + FOR VALUES IN (2,4,6,8); + +CREATE TABLE pa_source (sid integer, delta float); +-- insert many rows to the source table +INSERT INTO pa_source SELECT id, id * 10 FROM generate_series(1,14) AS id; +-- insert a few rows in the target table (odd numbered tid) +INSERT INTO pa_target SELECT '2017-01-31', id, id * 100, 'initial' FROM generate_series(1,9,3) AS id; +INSERT INTO pa_target SELECT '2017-02-28', id, id * 100, 'initial' FROM generate_series(2,9,3) AS id; + +-- try simple MERGE +BEGIN; +MERGE INTO pa_target t + USING (SELECT '2017-01-15' AS slogts, * FROM pa_source WHERE sid < 10) s + ON t.tid = s.sid + WHEN MATCHED THEN + UPDATE SET balance = balance + delta, val = val || ' updated by merge' + WHEN NOT MATCHED THEN + INSERT VALUES (slogts::timestamp, sid, delta, 'inserted by merge'); +SELECT * FROM pa_target ORDER BY tid; +ROLLBACK; + +DROP TABLE pa_source; +DROP TABLE pa_target CASCADE; + +-- some complex joins on the source side + +CREATE TABLE cj_target (tid integer, balance float, val text); +CREATE TABLE cj_source1 (sid1 integer, scat integer, delta integer); +CREATE TABLE cj_source2 (sid2 integer, sval text); +INSERT INTO cj_source1 VALUES (1, 10, 100); +INSERT INTO cj_source1 VALUES (1, 20, 200); +INSERT INTO cj_source1 VALUES (2, 20, 300); +INSERT INTO cj_source1 VALUES (3, 10, 400); +INSERT INTO cj_source2 VALUES (1, 'initial source2'); +INSERT INTO cj_source2 VALUES (2, 'initial source2'); +INSERT INTO cj_source2 VALUES (3, 'initial source2'); + +-- source relation is an unaliased join +MERGE INTO cj_target t +USING cj_source1 s1 + INNER JOIN cj_source2 s2 ON sid1 = sid2 +ON t.tid = sid1 +WHEN NOT MATCHED THEN + INSERT VALUES (sid1, delta, sval); + +-- try accessing columns from either side of the source join +MERGE INTO cj_target t +USING cj_source2 s2 + INNER JOIN cj_source1 s1 ON sid1 = sid2 AND scat = 20 +ON t.tid = sid1 +WHEN NOT MATCHED THEN + INSERT VALUES (sid2, delta, sval) +WHEN MATCHED THEN + DELETE; + +-- some simple expressions in INSERT targetlist +MERGE INTO cj_target t +USING cj_source2 s2 + INNER JOIN cj_source1 s1 ON sid1 = sid2 +ON t.tid = sid1 +WHEN NOT MATCHED THEN + INSERT VALUES (sid2, delta + scat, sval) +WHEN MATCHED THEN + UPDATE SET val = val || ' updated by merge'; + +MERGE INTO cj_target t +USING cj_source2 s2 + INNER JOIN cj_source1 s1 ON sid1 = sid2 AND scat = 20 +ON t.tid = sid1 +WHEN MATCHED THEN + UPDATE SET val = val || ' ' || delta::text; + +SELECT * FROM cj_target; + +ALTER TABLE cj_source1 RENAME COLUMN sid1 TO sid; +ALTER TABLE cj_source2 RENAME COLUMN sid2 TO sid; + +TRUNCATE cj_target; + +MERGE INTO cj_target t +USING cj_source1 s1 + INNER JOIN cj_source2 s2 ON s1.sid = s2.sid +ON t.tid = s1.sid +WHEN NOT MATCHED THEN + INSERT VALUES (s2.sid, delta, sval); + +DROP TABLE cj_source2, cj_source1, cj_target; + +-- Function scans +CREATE TABLE fs_target (a int, b int, c text); +MERGE INTO fs_target t +USING generate_series(1,100,1) AS id +ON t.a = id +WHEN MATCHED THEN + UPDATE SET b = b + id +WHEN NOT MATCHED THEN + INSERT VALUES (id, -1); + +MERGE INTO fs_target t +USING generate_series(1,100,2) AS id +ON t.a = id +WHEN MATCHED THEN + UPDATE SET b = b + id, c = 'updated '|| id.*::text +WHEN NOT MATCHED THEN + INSERT VALUES (id, -1, 'inserted ' || id.*::text); + +SELECT count(*) FROM fs_target; +DROP TABLE fs_target; + +-- SERIALIZABLE test +-- handled in isolation tests + +-- Inheritance-based partitioning +CREATE TABLE measurement ( + city_id int not null, + logdate date not null, + peaktemp int, + unitsales int +); +CREATE TABLE measurement_y2006m02 ( + CHECK ( logdate >= DATE '2006-02-01' AND logdate < DATE '2006-03-01' ) +) INHERITS (measurement); +CREATE TABLE measurement_y2006m03 ( + CHECK ( logdate >= DATE '2006-03-01' AND logdate < DATE '2006-04-01' ) +) INHERITS (measurement); +CREATE TABLE measurement_y2007m01 ( + filler text, + peaktemp int, + logdate date not null, + city_id int not null, + unitsales int + CHECK ( logdate >= DATE '2007-01-01' AND logdate < DATE '2007-02-01') +); +ALTER TABLE measurement_y2007m01 DROP COLUMN filler; +ALTER TABLE measurement_y2007m01 INHERIT measurement; + +CREATE OR REPLACE FUNCTION measurement_insert_trigger() +RETURNS TRIGGER AS $$ +BEGIN + IF ( NEW.logdate >= DATE '2006-02-01' AND + NEW.logdate < DATE '2006-03-01' ) THEN + INSERT INTO measurement_y2006m02 VALUES (NEW.*); + ELSIF ( NEW.logdate >= DATE '2006-03-01' AND + NEW.logdate < DATE '2006-04-01' ) THEN + INSERT INTO measurement_y2006m03 VALUES (NEW.*); + ELSIF ( NEW.logdate >= DATE '2007-01-01' AND + NEW.logdate < DATE '2007-02-01' ) THEN + INSERT INTO measurement_y2007m01 (city_id, logdate, peaktemp, unitsales) + VALUES (NEW.*); + ELSE + RAISE EXCEPTION 'Date out of range. Fix the measurement_insert_trigger() function!'; + END IF; + RETURN NULL; +END; +$$ LANGUAGE plpgsql ; +CREATE TRIGGER insert_measurement_trigger + BEFORE INSERT ON measurement + FOR EACH ROW EXECUTE PROCEDURE measurement_insert_trigger(); +INSERT INTO measurement VALUES (1, '2006-02-10', 35, 10); +INSERT INTO measurement VALUES (1, '2006-02-16', 45, 20); +INSERT INTO measurement VALUES (1, '2006-03-17', 25, 10); +INSERT INTO measurement VALUES (1, '2006-03-27', 15, 40); +INSERT INTO measurement VALUES (1, '2007-01-15', 10, 10); +INSERT INTO measurement VALUES (1, '2007-01-17', 10, 10); + +SELECT tableoid::regclass, * FROM measurement ORDER BY city_id, logdate; + +CREATE TABLE new_measurement (LIKE measurement); +INSERT INTO new_measurement VALUES (1, '2006-03-01', 20, 10); +INSERT INTO new_measurement VALUES (1, '2006-02-16', 50, 10); +INSERT INTO new_measurement VALUES (2, '2006-02-10', 20, 20); +INSERT INTO new_measurement VALUES (1, '2006-03-27', NULL, NULL); +INSERT INTO new_measurement VALUES (1, '2007-01-17', NULL, NULL); +INSERT INTO new_measurement VALUES (1, '2007-01-15', 5, NULL); +INSERT INTO new_measurement VALUES (1, '2007-01-16', 10, 10); + +MERGE into measurement m + USING new_measurement nm ON + (m.city_id = nm.city_id and m.logdate=nm.logdate) +WHEN MATCHED AND nm.peaktemp IS NULL THEN DELETE +WHEN MATCHED THEN UPDATE + SET peaktemp = greatest(m.peaktemp, nm.peaktemp), + unitsales = m.unitsales + coalesce(nm.unitsales, 0) +WHEN NOT MATCHED THEN INSERT + (city_id, logdate, peaktemp, unitsales) + VALUES (city_id, logdate, peaktemp, unitsales); + +SELECT tableoid::regclass, * FROM measurement ORDER BY city_id, logdate; +DROP TABLE measurement, new_measurement CASCADE; +DROP FUNCTION measurement_insert_trigger(); + +-- prepare + +RESET SESSION AUTHORIZATION; +DROP TABLE target, target2; +DROP TABLE source, source2; +DROP FUNCTION merge_trigfunc(); +DROP USER merge_privs; +DROP USER merge_no_privs; diff --git a/src/test/regress/sql/privileges.sql b/src/test/regress/sql/privileges.sql index c8c545b64c..3228572880 100644 --- a/src/test/regress/sql/privileges.sql +++ b/src/test/regress/sql/privileges.sql @@ -459,6 +459,114 @@ UPDATE atest5 SET one = 1; -- fail SELECT atest6 FROM atest6; -- ok COPY atest6 TO stdout; -- ok +-- test column privileges with MERGE +SET SESSION AUTHORIZATION regress_priv_user1; +CREATE TABLE mtarget (a int, b text); +CREATE TABLE msource (a int, b text); +INSERT INTO mtarget VALUES (1, 'init1'), (2, 'init2'); +INSERT INTO msource VALUES (1, 'source1'), (2, 'source2'), (3, 'source3'); + +GRANT SELECT (a) ON msource TO regress_priv_user4; +GRANT SELECT (a) ON mtarget TO regress_priv_user4; +GRANT INSERT (a,b) ON mtarget TO regress_priv_user4; +GRANT UPDATE (b) ON mtarget TO regress_priv_user4; + +SET SESSION AUTHORIZATION regress_priv_user4; + +-- +-- test source privileges +-- + +-- fail (no SELECT priv on s.b) +MERGE INTO mtarget t USING msource s ON t.a = s.a +WHEN MATCHED THEN + UPDATE SET b = s.b +WHEN NOT MATCHED THEN + INSERT VALUES (a, NULL); + +-- fail (s.b used in the INSERTed values) +MERGE INTO mtarget t USING msource s ON t.a = s.a +WHEN MATCHED THEN + UPDATE SET b = 'x' +WHEN NOT MATCHED THEN + INSERT VALUES (a, b); + +-- fail (s.b used in the WHEN quals) +MERGE INTO mtarget t USING msource s ON t.a = s.a +WHEN MATCHED AND s.b = 'x' THEN + UPDATE SET b = 'x' +WHEN NOT MATCHED THEN + INSERT VALUES (a, NULL); + +-- this should be ok since only s.a is accessed +BEGIN; +MERGE INTO mtarget t USING msource s ON t.a = s.a +WHEN MATCHED THEN + UPDATE SET b = 'ok' +WHEN NOT MATCHED THEN + INSERT VALUES (a, NULL); +ROLLBACK; + +SET SESSION AUTHORIZATION regress_priv_user1; +GRANT SELECT (b) ON msource TO regress_priv_user4; +SET SESSION AUTHORIZATION regress_priv_user4; + +-- should now be ok +BEGIN; +MERGE INTO mtarget t USING msource s ON t.a = s.a +WHEN MATCHED THEN + UPDATE SET b = s.b +WHEN NOT MATCHED THEN + INSERT VALUES (a, b); +ROLLBACK; + +-- +-- test target privileges +-- + +-- fail (no SELECT priv on t.b) +MERGE INTO mtarget t USING msource s ON t.a = s.a +WHEN MATCHED THEN + UPDATE SET b = t.b +WHEN NOT MATCHED THEN + INSERT VALUES (a, NULL); + +-- fail (no UPDATE on t.a) +MERGE INTO mtarget t USING msource s ON t.a = s.a +WHEN MATCHED THEN + UPDATE SET b = s.b, a = t.a + 1 +WHEN NOT MATCHED THEN + INSERT VALUES (a, b); + +-- fail (no SELECT on t.b) +MERGE INTO mtarget t USING msource s ON t.a = s.a +WHEN MATCHED AND t.b IS NOT NULL THEN + UPDATE SET b = s.b +WHEN NOT MATCHED THEN + INSERT VALUES (a, b); + +-- ok +BEGIN; +MERGE INTO mtarget t USING msource s ON t.a = s.a +WHEN MATCHED THEN + UPDATE SET b = s.b; +ROLLBACK; + +-- fail (no DELETE) +MERGE INTO mtarget t USING msource s ON t.a = s.a +WHEN MATCHED AND t.b IS NOT NULL THEN + DELETE; + +-- grant delete privileges +SET SESSION AUTHORIZATION regress_priv_user1; +GRANT DELETE ON mtarget TO regress_priv_user4; +-- should be ok now +BEGIN; +MERGE INTO mtarget t USING msource s ON t.a = s.a +WHEN MATCHED AND t.b IS NOT NULL THEN + DELETE; +ROLLBACK; + -- check error reporting with column privs SET SESSION AUTHORIZATION regress_priv_user1; CREATE TABLE t1 (c1 int, c2 int, c3 int check (c3 < 5), primary key (c1, c2)); diff --git a/src/test/regress/sql/rowsecurity.sql b/src/test/regress/sql/rowsecurity.sql index b310acdd27..febf3cc4cf 100644 --- a/src/test/regress/sql/rowsecurity.sql +++ b/src/test/regress/sql/rowsecurity.sql @@ -810,6 +810,162 @@ INSERT INTO document VALUES (4, (SELECT cid from category WHERE cname = 'novel') INSERT INTO document VALUES (1, (SELECT cid from category WHERE cname = 'novel'), 1, 'regress_rls_bob', 'my first novel') ON CONFLICT (did) DO UPDATE SET dauthor = 'regress_rls_carol'; +-- +-- MERGE +-- +RESET SESSION AUTHORIZATION; +DROP POLICY p3_with_all ON document; + +ALTER TABLE document ADD COLUMN dnotes text DEFAULT ''; +-- all documents are readable +CREATE POLICY p1 ON document FOR SELECT USING (true); +-- one may insert documents only authored by them +CREATE POLICY p2 ON document FOR INSERT WITH CHECK (dauthor = current_user); +-- one may only update documents in 'novel' category +CREATE POLICY p3 ON document FOR UPDATE + USING (cid = (SELECT cid from category WHERE cname = 'novel')) + WITH CHECK (dauthor = current_user); +-- one may only delete documents in 'manga' category +CREATE POLICY p4 ON document FOR DELETE + USING (cid = (SELECT cid from category WHERE cname = 'manga')); + +SELECT * FROM document; + +SET SESSION AUTHORIZATION regress_rls_bob; + +-- Fails, since update violates WITH CHECK qual on dauthor +MERGE INTO document d +USING (SELECT 1 as sdid) s +ON did = s.sdid +WHEN MATCHED THEN + UPDATE SET dnotes = dnotes || ' notes added by merge1 ', dauthor = 'regress_rls_alice'; + +-- Should be OK since USING and WITH CHECK quals pass +MERGE INTO document d +USING (SELECT 1 as sdid) s +ON did = s.sdid +WHEN MATCHED THEN + UPDATE SET dnotes = dnotes || ' notes added by merge2 '; + +-- Even when dauthor is updated explicitly, but to the existing value +MERGE INTO document d +USING (SELECT 1 as sdid) s +ON did = s.sdid +WHEN MATCHED THEN + UPDATE SET dnotes = dnotes || ' notes added by merge3 ', dauthor = 'regress_rls_bob'; + +-- There is a MATCH for did = 3, but UPDATE's USING qual does not allow +-- updating an item in category 'science fiction' +MERGE INTO document d +USING (SELECT 3 as sdid) s +ON did = s.sdid +WHEN MATCHED THEN + UPDATE SET dnotes = dnotes || ' notes added by merge '; + +-- The same thing with DELETE action, but fails again because no permissions +-- to delete items in 'science fiction' category that did 3 belongs to. +MERGE INTO document d +USING (SELECT 3 as sdid) s +ON did = s.sdid +WHEN MATCHED THEN + DELETE; + +-- Document with did 4 belongs to 'manga' category which is allowed for +-- deletion. But this fails because the UPDATE action is matched first and +-- UPDATE policy does not allow updation in the category. +MERGE INTO document d +USING (SELECT 4 as sdid) s +ON did = s.sdid +WHEN MATCHED AND dnotes = '' THEN + UPDATE SET dnotes = dnotes || ' notes added by merge ' +WHEN MATCHED THEN + DELETE; + +-- UPDATE action is not matched this time because of the WHEN qual. +-- DELETE still fails because role regress_rls_bob does not have SELECT +-- privileges on 'manga' category row in the category table. +MERGE INTO document d +USING (SELECT 4 as sdid) s +ON did = s.sdid +WHEN MATCHED AND dnotes <> '' THEN + UPDATE SET dnotes = dnotes || ' notes added by merge ' +WHEN MATCHED THEN + DELETE; + +SELECT * FROM document WHERE did = 4; + +-- Switch to regress_rls_carol role and try the DELETE again. It should succeed +-- this time +RESET SESSION AUTHORIZATION; +SET SESSION AUTHORIZATION regress_rls_carol; + +MERGE INTO document d +USING (SELECT 4 as sdid) s +ON did = s.sdid +WHEN MATCHED AND dnotes <> '' THEN + UPDATE SET dnotes = dnotes || ' notes added by merge ' +WHEN MATCHED THEN + DELETE; + +-- Switch back to regress_rls_bob role +RESET SESSION AUTHORIZATION; +SET SESSION AUTHORIZATION regress_rls_bob; + +-- Try INSERT action. This fails because we are trying to insert +-- dauthor = regress_rls_dave and INSERT's WITH CHECK does not allow +-- that +MERGE INTO document d +USING (SELECT 12 as sdid) s +ON did = s.sdid +WHEN MATCHED THEN + DELETE +WHEN NOT MATCHED THEN + INSERT VALUES (12, 11, 1, 'regress_rls_dave', 'another novel'); + +-- This should be fine +MERGE INTO document d +USING (SELECT 12 as sdid) s +ON did = s.sdid +WHEN MATCHED THEN + DELETE +WHEN NOT MATCHED THEN + INSERT VALUES (12, 11, 1, 'regress_rls_bob', 'another novel'); + +-- ok +MERGE INTO document d +USING (SELECT 1 as sdid) s +ON did = s.sdid +WHEN MATCHED THEN + UPDATE SET dnotes = dnotes || ' notes added by merge4 ' +WHEN NOT MATCHED THEN + INSERT VALUES (12, 11, 1, 'regress_rls_bob', 'another novel'); + +-- drop and create a new SELECT policy which prevents us from reading +-- any document except with category 'magna' +RESET SESSION AUTHORIZATION; +DROP POLICY p1 ON document; +CREATE POLICY p1 ON document FOR SELECT + USING (cid = (SELECT cid from category WHERE cname = 'manga')); + +SET SESSION AUTHORIZATION regress_rls_bob; + +-- MERGE can no longer see the matching row and hence attempts the +-- NOT MATCHED action, which results in unique key violation +MERGE INTO document d +USING (SELECT 1 as sdid) s +ON did = s.sdid +WHEN MATCHED THEN + UPDATE SET dnotes = dnotes || ' notes added by merge5 ' +WHEN NOT MATCHED THEN + INSERT VALUES (12, 11, 1, 'regress_rls_bob', 'another novel'); + +RESET SESSION AUTHORIZATION; +-- drop the restrictive SELECT policy so that we can look at the +-- final state of the table +DROP POLICY p1 ON document; +-- Just check everything went per plan +SELECT * FROM document; + -- -- ROLE/GROUP -- diff --git a/src/test/regress/sql/rules.sql b/src/test/regress/sql/rules.sql index aae2ba32e8..aee6abed86 100644 --- a/src/test/regress/sql/rules.sql +++ b/src/test/regress/sql/rules.sql @@ -1232,6 +1232,39 @@ CREATE RULE rules_parted_table_insert AS ON INSERT to rules_parted_table ALTER RULE rules_parted_table_insert ON rules_parted_table RENAME TO rules_parted_table_insert_redirect; DROP TABLE rules_parted_table; +-- +-- test MERGE +-- +CREATE TABLE rule_merge1 (a int, b text); +CREATE TABLE rule_merge2 (a int, b text); +CREATE RULE rule1 AS ON INSERT TO rule_merge1 + DO INSTEAD INSERT INTO rule_merge2 VALUES (NEW.*); +CREATE RULE rule2 AS ON UPDATE TO rule_merge1 + DO INSTEAD UPDATE rule_merge2 SET a = NEW.a, b = NEW.b + WHERE a = OLD.a; +CREATE RULE rule3 AS ON DELETE TO rule_merge1 + DO INSTEAD DELETE FROM rule_merge2 WHERE a = OLD.a; + +-- MERGE not supported for table with rules +MERGE INTO rule_merge1 t USING (SELECT 1 AS a) s + ON t.a = s.a + WHEN MATCHED AND t.a < 2 THEN + UPDATE SET b = b || ' updated by merge' + WHEN MATCHED AND t.a > 2 THEN + DELETE + WHEN NOT MATCHED THEN + INSERT VALUES (s.a, ''); + +-- should be ok with the other table though +MERGE INTO rule_merge2 t USING (SELECT 1 AS a) s + ON t.a = s.a + WHEN MATCHED AND t.a < 2 THEN + UPDATE SET b = b || ' updated by merge' + WHEN MATCHED AND t.a > 2 THEN + DELETE + WHEN NOT MATCHED THEN + INSERT VALUES (s.a, ''); + -- -- Test enabling/disabling -- diff --git a/src/test/regress/sql/triggers.sql b/src/test/regress/sql/triggers.sql index 4cc096265d..83cd00f54f 100644 --- a/src/test/regress/sql/triggers.sql +++ b/src/test/regress/sql/triggers.sql @@ -2439,6 +2439,53 @@ delete from self_ref where a = 1; drop table self_ref; +-- +-- test transition tables with MERGE +-- +create table merge_target_table (a int primary key, b text); +create trigger merge_target_table_insert_trig + after insert on merge_target_table referencing new table as new_table + for each statement execute procedure dump_insert(); +create trigger merge_target_table_update_trig + after update on merge_target_table referencing old table as old_table new table as new_table + for each statement execute procedure dump_update(); +create trigger merge_target_table_delete_trig + after delete on merge_target_table referencing old table as old_table + for each statement execute procedure dump_delete(); + +create table merge_source_table (a int, b text); +insert into merge_source_table + values (1, 'initial1'), (2, 'initial2'), + (3, 'initial3'), (4, 'initial4'); + +merge into merge_target_table t +using merge_source_table s +on t.a = s.a +when not matched then + insert values (a, b); + +merge into merge_target_table t +using merge_source_table s +on t.a = s.a +when matched and s.a <= 2 then + update set b = t.b || ' updated by merge' +when matched and s.a > 2 then + delete +when not matched then + insert values (a, b); + +merge into merge_target_table t +using merge_source_table s +on t.a = s.a +when matched and s.a <= 2 then + update set b = t.b || ' updated again by merge' +when matched and s.a > 2 then + delete +when not matched then + insert values (a, b); + +drop table merge_source_table, merge_target_table; + -- cleanup drop function dump_insert(); drop function dump_update(); diff --git a/src/test/regress/sql/with.sql b/src/test/regress/sql/with.sql index e482177557..f1ea3ae22e 100644 --- a/src/test/regress/sql/with.sql +++ b/src/test/regress/sql/with.sql @@ -1270,6 +1270,62 @@ RETURNING k, v; DROP TABLE withz; +-- WITH referenced by MERGE statement +CREATE TABLE m AS SELECT i AS k, (i || ' v')::text v FROM generate_series(1, 16, 3) i; +ALTER TABLE m ADD UNIQUE (k); + +WITH RECURSIVE cte_basic AS (SELECT 1 a, 'cte_basic val' b) +MERGE INTO m USING (select 0 k, 'merge source SubPlan' v) o ON m.k=o.k +WHEN MATCHED THEN UPDATE SET v = (SELECT b || ' merge update' FROM cte_basic WHERE cte_basic.a = m.k LIMIT 1) +WHEN NOT MATCHED THEN INSERT VALUES(o.k, o.v); + +-- Basic: +WITH cte_basic AS MATERIALIZED (SELECT 1 a, 'cte_basic val' b) +MERGE INTO m USING (select 0 k, 'merge source SubPlan' v offset 0) o ON m.k=o.k +WHEN MATCHED THEN UPDATE SET v = (SELECT b || ' merge update' FROM cte_basic WHERE cte_basic.a = m.k LIMIT 1) +WHEN NOT MATCHED THEN INSERT VALUES(o.k, o.v); +-- Examine +SELECT * FROM m where k = 0; + +-- See EXPLAIN output for same query: +EXPLAIN (VERBOSE, COSTS OFF) +WITH cte_basic AS MATERIALIZED (SELECT 1 a, 'cte_basic val' b) +MERGE INTO m USING (select 0 k, 'merge source SubPlan' v offset 0) o ON m.k=o.k +WHEN MATCHED THEN UPDATE SET v = (SELECT b || ' merge update' FROM cte_basic WHERE cte_basic.a = m.k LIMIT 1) +WHEN NOT MATCHED THEN INSERT VALUES(o.k, o.v); + +-- InitPlan +WITH cte_init AS MATERIALIZED (SELECT 1 a, 'cte_init val' b) +MERGE INTO m USING (select 1 k, 'merge source InitPlan' v offset 0) o ON m.k=o.k +WHEN MATCHED THEN UPDATE SET v = (SELECT b || ' merge update' FROM cte_init WHERE a = 1 LIMIT 1) +WHEN NOT MATCHED THEN INSERT VALUES(o.k, o.v); +-- Examine +SELECT * FROM m where k = 1; + +-- See EXPLAIN output for same query: +EXPLAIN (VERBOSE, COSTS OFF) +WITH cte_init AS MATERIALIZED (SELECT 1 a, 'cte_init val' b) +MERGE INTO m USING (select 1 k, 'merge source InitPlan' v offset 0) o ON m.k=o.k +WHEN MATCHED THEN UPDATE SET v = (SELECT b || ' merge update' FROM cte_init WHERE a = 1 LIMIT 1) +WHEN NOT MATCHED THEN INSERT VALUES(o.k, o.v); + +-- MERGE source comes from CTE: +WITH merge_source_cte AS MATERIALIZED (SELECT 15 a, 'merge_source_cte val' b) +MERGE INTO m USING (select * from merge_source_cte) o ON m.k=o.a +WHEN MATCHED THEN UPDATE SET v = (SELECT b || merge_source_cte.*::text || ' merge update' FROM merge_source_cte WHERE a = 15) +WHEN NOT MATCHED THEN INSERT VALUES(o.a, o.b || (SELECT merge_source_cte.*::text || ' merge insert' FROM merge_source_cte)); +-- Examine +SELECT * FROM m where k = 15; + +-- See EXPLAIN output for same query: +EXPLAIN (VERBOSE, COSTS OFF) +WITH merge_source_cte AS MATERIALIZED (SELECT 15 a, 'merge_source_cte val' b) +MERGE INTO m USING (select * from merge_source_cte) o ON m.k=o.a +WHEN MATCHED THEN UPDATE SET v = (SELECT b || merge_source_cte.*::text || ' merge update' FROM merge_source_cte WHERE a = 15) +WHEN NOT MATCHED THEN INSERT VALUES(o.a, o.b || (SELECT merge_source_cte.*::text || ' merge insert' FROM merge_source_cte)); + +DROP TABLE m; + -- check that run to completion happens in proper ordering TRUNCATE TABLE y; diff --git a/src/tools/pgindent/typedefs.list b/src/tools/pgindent/typedefs.list index 85c808af90..182b233b4c 100644 --- a/src/tools/pgindent/typedefs.list +++ b/src/tools/pgindent/typedefs.list @@ -1441,6 +1441,8 @@ MemoryContextCounters MemoryContextData MemoryContextMethods MemoryStatsPrintFunc +MergeAction +MergeActionState MergeAppend MergeAppendPath MergeAppendState @@ -1449,6 +1451,8 @@ MergeJoinClause MergeJoinState MergePath MergeScanSelCache +MergeStmt +MergeWhenClause MetaCommand MinMaxAggInfo MinMaxAggPath