mirror of
https://github.com/postgres/postgres.git
synced 2025-09-02 04:21:28 +03:00
MERGE SQL Command following SQL:2016
MERGE performs actions that modify rows in the target table using a source table or query. MERGE provides a single SQL statement that can conditionally INSERT/UPDATE/DELETE rows a task that would other require multiple PL statements. e.g. MERGE INTO target AS t USING source AS s ON t.tid = s.sid WHEN MATCHED AND t.balance > s.delta THEN UPDATE SET balance = t.balance - s.delta WHEN MATCHED THEN DELETE WHEN NOT MATCHED AND s.delta > 0 THEN INSERT VALUES (s.sid, s.delta) WHEN NOT MATCHED THEN DO NOTHING; MERGE works with regular and partitioned tables, including column and row security enforcement, as well as support for row, statement and transition triggers. MERGE is optimized for OLTP and is parameterizable, though also useful for large scale ETL/ELT. MERGE is not intended to be used in preference to existing single SQL commands for INSERT, UPDATE or DELETE since there is some overhead. MERGE can be used statically from PL/pgSQL. MERGE does not yet support inheritance, write rules, RETURNING clauses, updatable views or foreign tables. MERGE follows SQL Standard per the most recent SQL:2016. Includes full tests and documentation, including full isolation tests to demonstrate the concurrent behavior. This version written from scratch in 2017 by Simon Riggs, using docs and tests originally written in 2009. Later work from Pavan Deolasee has been both complex and deep, leaving the lead author credit now in his hands. Extensive discussion of concurrency from Peter Geoghegan, with thanks for the time and effort contributed. Various issues reported via sqlsmith by Andreas Seltenreich Authors: Pavan Deolasee, Simon Riggs Reviewer: Peter Geoghegan, Amit Langote, Tomas Vondra, Simon Riggs Discussion: https://postgr.es/m/CANP8+jKitBSrB7oTgT9CY2i1ObfOt36z0XMraQc+Xrz8QB0nXA@mail.gmail.com https://postgr.es/m/CAH2-WzkJdBuxj9PO=2QaO9-3h3xGbQPZ34kJH=HukRekwM-GZg@mail.gmail.com
This commit is contained in:
@@ -3917,9 +3917,11 @@ char *PQcmdTuples(PGresult *res);
|
||||
<structname>PGresult</structname>. This function can only be used following
|
||||
the execution of a <command>SELECT</command>, <command>CREATE TABLE AS</command>,
|
||||
<command>INSERT</command>, <command>UPDATE</command>, <command>DELETE</command>,
|
||||
<command>MOVE</command>, <command>FETCH</command>, or <command>COPY</command> statement,
|
||||
or an <command>EXECUTE</command> of a prepared query that contains an
|
||||
<command>INSERT</command>, <command>UPDATE</command>, or <command>DELETE</command> statement.
|
||||
<command>MERGE</command>, <command>MOVE</command>, <command>FETCH</command>,
|
||||
or <command>COPY</command> statement, or an <command>EXECUTE</command> of a
|
||||
prepared query that contains an <command>INSERT</command>,
|
||||
<command>UPDATE</command>, <command>DELETE</command>
|
||||
or <command>MERGE</command> statement.
|
||||
If the command that generated the <structname>PGresult</structname> was anything
|
||||
else, <function>PQcmdTuples</function> returns an empty string. The caller
|
||||
should not free the return value directly. It will be freed when
|
||||
|
@@ -422,6 +422,31 @@ COMMIT;
|
||||
<literal>11</literal>, which no longer matches the criteria.
|
||||
</para>
|
||||
|
||||
<para>
|
||||
The <command>MERGE</command> allows the user to specify various combinations
|
||||
of <command>INSERT</command>, <command>UPDATE</command> or
|
||||
<command>DELETE</command> subcommands. A <command>MERGE</command> command
|
||||
with both <command>INSERT</command> and <command>UPDATE</command>
|
||||
subcommands looks similar to <command>INSERT</command> with an
|
||||
<literal>ON CONFLICT DO UPDATE</literal> clause but does not guarantee
|
||||
that either <command>INSERT</command> and <command>UPDATE</command> 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 latest version of the row, using standard
|
||||
EvalPlanQual. MERGE actions can be conditional, so conditions must be
|
||||
re-evaluated on the latest row, starting from the first action.
|
||||
|
||||
On the other hand, if the row is concurrently updated or deleted so that
|
||||
the join condition fails, then MERGE will execute a NOT MATCHED action, if it
|
||||
exists and the AND WHEN qual evaluates to true.
|
||||
|
||||
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 attempting an UPDATE.
|
||||
</para>
|
||||
|
||||
<para>
|
||||
Because Read Committed mode starts each command with a new snapshot
|
||||
that includes all transactions committed up to that instant,
|
||||
@@ -900,7 +925,8 @@ ERROR: could not serialize access due to read/write dependencies among transact
|
||||
|
||||
<para>
|
||||
The commands <command>UPDATE</command>,
|
||||
<command>DELETE</command>, and <command>INSERT</command>
|
||||
<command>DELETE</command>, <command>INSERT</command> and
|
||||
<command>MERGE</command>
|
||||
acquire this lock mode on the target table (in addition to
|
||||
<literal>ACCESS SHARE</literal> locks on any other referenced
|
||||
tables). In general, this lock mode will be acquired by any
|
||||
|
@@ -1246,7 +1246,7 @@ EXECUTE format('SELECT count(*) FROM %I '
|
||||
</programlisting>
|
||||
Another restriction on parameter symbols is that they only work in
|
||||
<command>SELECT</command>, <command>INSERT</command>, <command>UPDATE</command>, and
|
||||
<command>DELETE</command> commands. In other statement
|
||||
<command>DELETE</command> and <command>MERGE</command> commands. In other statement
|
||||
types (generically called utility statements), you must insert
|
||||
values textually even if they are just data values.
|
||||
</para>
|
||||
@@ -1529,6 +1529,7 @@ GET DIAGNOSTICS integer_var = ROW_COUNT;
|
||||
<listitem>
|
||||
<para>
|
||||
<command>UPDATE</command>, <command>INSERT</command>, and <command>DELETE</command>
|
||||
and <command>MERGE</command>
|
||||
statements set <literal>FOUND</literal> true if at least one
|
||||
row is affected, false if no row is affected.
|
||||
</para>
|
||||
|
@@ -159,6 +159,7 @@ Complete list of usable sgml source files in this directory.
|
||||
<!ENTITY load SYSTEM "load.sgml">
|
||||
<!ENTITY lock SYSTEM "lock.sgml">
|
||||
<!ENTITY move SYSTEM "move.sgml">
|
||||
<!ENTITY merge SYSTEM "merge.sgml">
|
||||
<!ENTITY notify SYSTEM "notify.sgml">
|
||||
<!ENTITY prepare SYSTEM "prepare.sgml">
|
||||
<!ENTITY prepareTransaction SYSTEM "prepare_transaction.sgml">
|
||||
|
@@ -94,6 +94,13 @@ CREATE POLICY <replaceable class="parameter">name</replaceable> ON <replaceable
|
||||
exist, a <quote>default deny</quote> policy is assumed, so that no rows will
|
||||
be visible or updatable.
|
||||
</para>
|
||||
|
||||
<para>
|
||||
No separate policy exists for <command>MERGE</command>. Instead policies
|
||||
defined for <literal>SELECT</literal>, <literal>INSERT</literal>,
|
||||
<literal>UPDATE</literal> and <literal>DELETE</literal> are applied
|
||||
while executing MERGE, depending on the actions that are activated.
|
||||
</para>
|
||||
</refsect1>
|
||||
|
||||
<refsect1>
|
||||
|
@@ -579,6 +579,13 @@ INSERT <replaceable>oid</replaceable> <replaceable class="parameter">count</repl
|
||||
is a partition, an error will occur if one of the input rows violates
|
||||
the partition constraint.
|
||||
</para>
|
||||
|
||||
<para>
|
||||
You may also wish to consider using <command>MERGE</command>, since that
|
||||
allows mixed <command>INSERT</command>, <command>UPDATE</command> and
|
||||
<command>DELETE</command> within a single statement.
|
||||
See <xref linkend="sql-merge"/>.
|
||||
</para>
|
||||
</refsect1>
|
||||
|
||||
<refsect1>
|
||||
@@ -749,7 +756,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 <literal>VALUES</literal> clause or <replaceable>query</replaceable>,
|
||||
is disallowed by the standard.
|
||||
is disallowed by the standard. If you prefer a more SQL Standard
|
||||
conforming statement than <literal>ON CONFLICT</literal>, see
|
||||
<xref linkend="sql-merge"/>.
|
||||
</para>
|
||||
|
||||
<para>
|
||||
|
@@ -186,6 +186,7 @@
|
||||
&listen;
|
||||
&load;
|
||||
&lock;
|
||||
&merge;
|
||||
&move;
|
||||
¬ify;
|
||||
&prepare;
|
||||
|
@@ -182,6 +182,26 @@
|
||||
will be fired.
|
||||
</para>
|
||||
|
||||
<para>
|
||||
No separate triggers are defined for <command>MERGE</command>. Instead,
|
||||
statement-level or row-level <command>UPDATE</command>,
|
||||
<command>DELETE</command> and <command>INSERT</command> triggers are fired
|
||||
depending on what actions are specified in the <command>MERGE</command> query
|
||||
and what actions are activated.
|
||||
</para>
|
||||
|
||||
<para>
|
||||
While running a <command>MERGE</command> command, statement-level
|
||||
<literal>BEFORE</literal> and <literal>AFTER</literal> triggers are fired for
|
||||
events specified in the actions of the <command>MERGE</command> command,
|
||||
irrespective of whether the action is finally activated or not. This is same as
|
||||
an <command>UPDATE</command> 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 type of action, no
|
||||
row-level triggers are fired for the same kind of action.
|
||||
</para>
|
||||
|
||||
<para>
|
||||
Trigger functions invoked by per-statement triggers should always
|
||||
return <symbol>NULL</symbol>. Trigger functions invoked by per-row
|
||||
|
Reference in New Issue
Block a user