mirror of
https://github.com/postgres/postgres.git
synced 2025-12-21 05:21:08 +03:00
Add RETURNING support to MERGE.
This allows a RETURNING clause to be appended to a MERGE query, to return values based on each row inserted, updated, or deleted. As with plain INSERT, UPDATE, and DELETE commands, the returned values are based on the new contents of the target table for INSERT and UPDATE actions, and on its old contents for DELETE actions. Values from the source relation may also be returned. As with INSERT/UPDATE/DELETE, the output of MERGE ... RETURNING may be used as the source relation for other operations such as WITH queries and COPY commands. Additionally, a special function merge_action() is provided, which returns 'INSERT', 'UPDATE', or 'DELETE', depending on the action executed for each row. The merge_action() function can be used anywhere in the RETURNING list, including in arbitrary expressions and subqueries, but it is an error to use it anywhere outside of a MERGE query's RETURNING list. Dean Rasheed, reviewed by Isaac Morland, Vik Fearing, Alvaro Herrera, Gurjeet Singh, Jian He, Jeff Davis, Merlin Moncure, Peter Eisentraut, and Wolfgang Walther. Discussion: http://postgr.es/m/CAEZATCWePEGQR5LBn-vD6SfeLZafzEm2Qy_L_Oky2=qw2w3Pzg@mail.gmail.com
This commit is contained in:
@@ -130,16 +130,19 @@ COPY { <replaceable class="parameter">table_name</replaceable> [ ( <replaceable
|
||||
A <link linkend="sql-select"><command>SELECT</command></link>,
|
||||
<link linkend="sql-values"><command>VALUES</command></link>,
|
||||
<link linkend="sql-insert"><command>INSERT</command></link>,
|
||||
<link linkend="sql-update"><command>UPDATE</command></link>, or
|
||||
<link linkend="sql-delete"><command>DELETE</command></link> command whose results are to be
|
||||
copied. Note that parentheses are required around the query.
|
||||
<link linkend="sql-update"><command>UPDATE</command></link>,
|
||||
<link linkend="sql-delete"><command>DELETE</command></link>, or
|
||||
<link linkend="sql-merge"><command>MERGE</command></link> command
|
||||
whose results are to be copied. Note that parentheses are required
|
||||
around the query.
|
||||
</para>
|
||||
<para>
|
||||
For <command>INSERT</command>, <command>UPDATE</command> and
|
||||
<command>DELETE</command> queries a <literal>RETURNING</literal> clause
|
||||
must be provided, and the target relation must not have a conditional
|
||||
rule, nor an <literal>ALSO</literal> rule, nor an
|
||||
<literal>INSTEAD</literal> rule that expands to multiple statements.
|
||||
For <command>INSERT</command>, <command>UPDATE</command>,
|
||||
<command>DELETE</command>, and <command>MERGE</command> queries a
|
||||
<literal>RETURNING</literal> clause must be provided, and the target
|
||||
relation must not have a conditional rule, nor an
|
||||
<literal>ALSO</literal> rule, nor an <literal>INSTEAD</literal> rule
|
||||
that expands to multiple statements.
|
||||
</para>
|
||||
</listitem>
|
||||
</varlistentry>
|
||||
|
||||
@@ -25,6 +25,7 @@ PostgreSQL documentation
|
||||
MERGE INTO [ ONLY ] <replaceable class="parameter">target_table_name</replaceable> [ * ] [ [ AS ] <replaceable class="parameter">target_alias</replaceable> ]
|
||||
USING <replaceable class="parameter">data_source</replaceable> ON <replaceable class="parameter">join_condition</replaceable>
|
||||
<replaceable class="parameter">when_clause</replaceable> [...]
|
||||
[ RETURNING * | <replaceable class="parameter">output_expression</replaceable> [ [ AS ] <replaceable class="parameter">output_name</replaceable> ] [, ...] ]
|
||||
|
||||
<phrase>where <replaceable class="parameter">data_source</replaceable> is:</phrase>
|
||||
|
||||
@@ -96,6 +97,18 @@ DELETE
|
||||
more fine-grained handling.
|
||||
</para>
|
||||
|
||||
<para>
|
||||
The optional <literal>RETURNING</literal> clause causes <command>MERGE</command>
|
||||
to compute and return value(s) based on each row inserted, updated, or
|
||||
deleted. Any expression using the source or target table's columns, or
|
||||
the <xref linkend="merge_action"/> function can be computed. When an
|
||||
<command>INSERT</command> or <command>UPDATE</command> action is performed,
|
||||
the new values of the target table's columns are used. When a
|
||||
<command>DELETE</command> is performed, the old values of the target table's
|
||||
columns are used. The syntax of the <literal>RETURNING</literal> list is
|
||||
identical to that of the output list of <command>SELECT</command>.
|
||||
</para>
|
||||
|
||||
<para>
|
||||
There is no separate <literal>MERGE</literal> privilege.
|
||||
If you specify an update action, you must have the
|
||||
@@ -442,6 +455,36 @@ DELETE
|
||||
</listitem>
|
||||
</varlistentry>
|
||||
|
||||
<varlistentry>
|
||||
<term><replaceable class="parameter">output_expression</replaceable></term>
|
||||
<listitem>
|
||||
<para>
|
||||
An expression to be computed and returned by the <command>MERGE</command>
|
||||
command after each row is changed (whether inserted, updated, or deleted).
|
||||
The expression can use any columns of the source or target tables, or the
|
||||
<xref linkend="merge_action"/> function to return additional information
|
||||
about the action executed.
|
||||
</para>
|
||||
<para>
|
||||
Writing <literal>*</literal> will return all columns from the source
|
||||
table, followed by all columns from the target table. Often this will
|
||||
lead to a lot of duplication, since it is common for the source and
|
||||
target tables to have a lot of the same columns. This can be avoided by
|
||||
qualifying the <literal>*</literal> with the name or alias of the source
|
||||
or target table.
|
||||
</para>
|
||||
</listitem>
|
||||
</varlistentry>
|
||||
|
||||
<varlistentry>
|
||||
<term><replaceable class="parameter">output_name</replaceable></term>
|
||||
<listitem>
|
||||
<para>
|
||||
A name to use for a returned column.
|
||||
</para>
|
||||
</listitem>
|
||||
</varlistentry>
|
||||
|
||||
</variablelist>
|
||||
</refsect1>
|
||||
|
||||
@@ -460,6 +503,13 @@ MERGE <replaceable class="parameter">total_count</replaceable>
|
||||
were changed in any way.
|
||||
</para>
|
||||
|
||||
<para>
|
||||
If the <command>MERGE</command> command contains a <literal>RETURNING</literal>
|
||||
clause, the result will be similar to that of a <command>SELECT</command>
|
||||
statement containing the columns and values defined in the
|
||||
<literal>RETURNING</literal> list, computed over the row(s) inserted, updated,
|
||||
or deleted by the command.
|
||||
</para>
|
||||
</refsect1>
|
||||
|
||||
<refsect1>
|
||||
@@ -579,13 +629,6 @@ MERGE <replaceable class="parameter">total_count</replaceable>
|
||||
needed to avoid deadlocks between concurrent transactions.
|
||||
</para>
|
||||
|
||||
<para>
|
||||
There is no <literal>RETURNING</literal> clause with
|
||||
<command>MERGE</command>. Actions of <command>INSERT</command>,
|
||||
<command>UPDATE</command> and <command>DELETE</command> cannot contain
|
||||
<literal>RETURNING</literal> or <literal>WITH</literal> clauses.
|
||||
</para>
|
||||
|
||||
<para>
|
||||
When <command>MERGE</command> is run concurrently with other commands
|
||||
that modify the target table, the usual transaction isolation rules
|
||||
@@ -638,7 +681,8 @@ WHEN NOT MATCHED THEN
|
||||
<para>
|
||||
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.
|
||||
item. Don't allow entries that have zero stock. Return details of all
|
||||
changes made.
|
||||
<programlisting>
|
||||
MERGE INTO wines w
|
||||
USING wine_stock_changes s
|
||||
@@ -648,7 +692,8 @@ WHEN NOT MATCHED AND s.stock_delta > 0 THEN
|
||||
WHEN MATCHED AND w.stock + s.stock_delta > 0 THEN
|
||||
UPDATE SET stock = w.stock + s.stock_delta
|
||||
WHEN MATCHED THEN
|
||||
DELETE;
|
||||
DELETE
|
||||
RETURNING merge_action(), w.*;
|
||||
</programlisting>
|
||||
|
||||
The <literal>wine_stock_changes</literal> table might be, for example, a
|
||||
@@ -663,8 +708,9 @@ WHEN MATCHED THEN
|
||||
This command conforms to the <acronym>SQL</acronym> standard.
|
||||
</para>
|
||||
<para>
|
||||
The <literal>WITH</literal> clause and <literal>DO NOTHING</literal>
|
||||
action are extensions to the <acronym>SQL</acronym> standard.
|
||||
The <literal>WITH</literal> clause, <literal>DO NOTHING</literal> action,
|
||||
and <literal>RETURNING</literal> clause are extensions to the
|
||||
<acronym>SQL</acronym> standard.
|
||||
</para>
|
||||
</refsect1>
|
||||
</refentry>
|
||||
|
||||
@@ -74,7 +74,7 @@ SELECT [ ALL | DISTINCT [ ON ( <replaceable class="parameter">expression</replac
|
||||
|
||||
<phrase>and <replaceable class="parameter">with_query</replaceable> is:</phrase>
|
||||
|
||||
<replaceable class="parameter">with_query_name</replaceable> [ ( <replaceable class="parameter">column_name</replaceable> [, ...] ) ] AS [ [ NOT ] MATERIALIZED ] ( <replaceable class="parameter">select</replaceable> | <replaceable class="parameter">values</replaceable> | <replaceable class="parameter">insert</replaceable> | <replaceable class="parameter">update</replaceable> | <replaceable class="parameter">delete</replaceable> )
|
||||
<replaceable class="parameter">with_query_name</replaceable> [ ( <replaceable class="parameter">column_name</replaceable> [, ...] ) ] AS [ [ NOT ] MATERIALIZED ] ( <replaceable class="parameter">select</replaceable> | <replaceable class="parameter">values</replaceable> | <replaceable class="parameter">insert</replaceable> | <replaceable class="parameter">update</replaceable> | <replaceable class="parameter">delete</replaceable> | <replaceable class="parameter">merge</replaceable> )
|
||||
[ SEARCH { BREADTH | DEPTH } FIRST BY <replaceable>column_name</replaceable> [, ...] SET <replaceable>search_seq_col_name</replaceable> ]
|
||||
[ CYCLE <replaceable>column_name</replaceable> [, ...] SET <replaceable>cycle_mark_col_name</replaceable> [ TO <replaceable>cycle_mark_value</replaceable> DEFAULT <replaceable>cycle_mark_default</replaceable> ] USING <replaceable>cycle_path_col_name</replaceable> ]
|
||||
|
||||
@@ -230,10 +230,10 @@ TABLE [ ONLY ] <replaceable class="parameter">table_name</replaceable> [ * ]
|
||||
The subqueries effectively act as temporary tables or views
|
||||
for the duration of the primary query.
|
||||
Each subquery can be a <command>SELECT</command>, <command>TABLE</command>, <command>VALUES</command>,
|
||||
<command>INSERT</command>, <command>UPDATE</command> or
|
||||
<command>DELETE</command> statement.
|
||||
<command>INSERT</command>, <command>UPDATE</command>,
|
||||
<command>DELETE</command>, or <command>MERGE</command> statement.
|
||||
When writing a data-modifying statement (<command>INSERT</command>,
|
||||
<command>UPDATE</command> or <command>DELETE</command>) in
|
||||
<command>UPDATE</command>, <command>DELETE</command>, or <command>MERGE</command>) in
|
||||
<literal>WITH</literal>, it is usual to include a <literal>RETURNING</literal> clause.
|
||||
It is the output of <literal>RETURNING</literal>, <emphasis>not</emphasis> the underlying
|
||||
table that the statement modifies, that forms the temporary table that is
|
||||
@@ -2184,7 +2184,8 @@ SELECT 2+2;
|
||||
|
||||
<para>
|
||||
<productname>PostgreSQL</productname> allows <command>INSERT</command>,
|
||||
<command>UPDATE</command>, and <command>DELETE</command> to be used as <literal>WITH</literal>
|
||||
<command>UPDATE</command>, <command>DELETE</command>, and
|
||||
<command>MERGE</command> to be used as <literal>WITH</literal>
|
||||
queries. This is not found in the SQL standard.
|
||||
</para>
|
||||
</refsect2>
|
||||
|
||||
Reference in New Issue
Block a user