1
0
mirror of https://github.com/postgres/postgres.git synced 2025-07-27 12:41:57 +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:
Dean Rasheed
2024-03-17 13:58:59 +00:00
parent 6a004f1be8
commit c649fa24a4
61 changed files with 1198 additions and 216 deletions

View File

@ -283,10 +283,15 @@ DELETE FROM products;
<secondary>RETURNING</secondary>
</indexterm>
<indexterm zone="dml-returning">
<primary>MERGE</primary>
<secondary>RETURNING</secondary>
</indexterm>
<para>
Sometimes it is useful to obtain data from modified rows while they are
being manipulated. The <command>INSERT</command>, <command>UPDATE</command>,
and <command>DELETE</command> commands all have an
<command>DELETE</command>, and <command>MERGE</command> commands all have an
optional <literal>RETURNING</literal> clause that supports this. Use
of <literal>RETURNING</literal> avoids performing an extra database query to
collect the data, and is especially valuable when it would otherwise be
@ -339,6 +344,21 @@ DELETE FROM products
</programlisting>
</para>
<para>
In a <command>MERGE</command>, the data available to <literal>RETURNING</literal> is
the content of the source row plus the content of the inserted, updated, or
deleted target row. Since it is quite common for the source and target to
have many of the same columns, specifying <literal>RETURNING *</literal>
can lead to a lot of duplicated columns, so it is often more useful to
qualify it so as to return just the source or target row. For example:
<programlisting>
MERGE INTO products p USING new_products n ON p.product_no = n.product_no
WHEN NOT MATCHED THEN INSERT VALUES (n.product_no, n.name, n.price)
WHEN MATCHED THEN UPDATE SET name = n.name, price = n.price
RETURNING p.*;
</programlisting>
</para>
<para>
If there are triggers (<xref linkend="triggers"/>) on the target table,
the data available to <literal>RETURNING</literal> is the row as modified by

View File

@ -22421,6 +22421,85 @@ SELECT count(*) FROM sometable;
</sect1>
<sect1 id="functions-merge-support">
<title>Merge Support Functions</title>
<indexterm>
<primary>MERGE</primary>
<secondary>RETURNING</secondary>
</indexterm>
<para>
<productname>PostgreSQL</productname> includes one merge support function
that may be used in the <literal>RETURNING</literal> list of a
<xref linkend="sql-merge"/> command to identify the action taken for each
row.
</para>
<table id="functions-merge-support-table">
<title>Merge Support Functions</title>
<tgroup cols="1">
<thead>
<row>
<entry role="func_table_entry"><para role="func_signature">
Function
</para>
<para>
Description
</para></entry>
</row>
</thead>
<tbody>
<row>
<entry role="func_table_entry"><para role="func_signature">
<indexterm>
<primary>merge_action</primary>
</indexterm>
<function id="merge_action">merge_action</function> ( )
<returnvalue>text</returnvalue>
</para>
<para>
Returns the merge action command executed for the current row. This
will be <literal>'INSERT'</literal>, <literal>'UPDATE'</literal>, or
<literal>'DELETE'</literal>.
</para></entry>
</row>
</tbody>
</tgroup>
</table>
<para>
Example:
<screen><![CDATA[
MERGE INTO products p
USING stock s ON p.product_id = s.product_id
WHEN MATCHED AND s.quantity > 0 THEN
UPDATE SET in_stock = true, quantity = s.quantity
WHEN MATCHED THEN
UPDATE SET in_stock = false, quantity = 0
WHEN NOT MATCHED THEN
INSERT (product_id, in_stock, quantity)
VALUES (s.product_id, true, s.quantity)
RETURNING merge_action(), p.*;
merge_action | product_id | in_stock | quantity
--------------+------------+----------+----------
UPDATE | 1001 | t | 50
UPDATE | 1002 | f | 0
INSERT | 1003 | t | 10
]]></screen>
</para>
<para>
Note that this function can only be used in the <literal>RETURNING</literal>
list of a <command>MERGE</command> command. It is an error to use it in any
other part of a query.
</para>
</sect1>
<sect1 id="functions-subquery">
<title>Subquery Expressions</title>

View File

@ -1442,9 +1442,9 @@
to a <glossterm linkend="glossary-client">client</glossterm> upon the
completion of an <acronym>SQL</acronym> command, usually a
<command>SELECT</command> but it can be an
<command>INSERT</command>, <command>UPDATE</command>, or
<command>DELETE</command> command if the <literal>RETURNING</literal>
clause is specified.
<command>INSERT</command>, <command>UPDATE</command>,
<command>DELETE</command>, or <command>MERGE</command> command if the
<literal>RETURNING</literal> clause is specified.
</para>
<para>
The fact that a result set is a relation means that a query can be used

View File

@ -1043,8 +1043,8 @@ INSERT INTO mytable VALUES (1,'one'), (2,'two');
</para>
<para>
If the command does return rows (for example <command>SELECT</command>,
or <command>INSERT</command>/<command>UPDATE</command>/<command>DELETE</command>
If the command does return rows (for example <command>SELECT</command>, or
<command>INSERT</command>/<command>UPDATE</command>/<command>DELETE</command>/<command>MERGE</command>
with <literal>RETURNING</literal>), there are two ways to proceed.
When the command will return at most one row, or you only care about
the first row of output, write the command as usual but add
@ -1172,6 +1172,7 @@ SELECT <replaceable>select_expressions</replaceable> INTO <optional>STRICT</opti
INSERT ... RETURNING <replaceable>expressions</replaceable> INTO <optional>STRICT</optional> <replaceable>target</replaceable>;
UPDATE ... RETURNING <replaceable>expressions</replaceable> INTO <optional>STRICT</optional> <replaceable>target</replaceable>;
DELETE ... RETURNING <replaceable>expressions</replaceable> INTO <optional>STRICT</optional> <replaceable>target</replaceable>;
MERGE ... RETURNING <replaceable>expressions</replaceable> INTO <optional>STRICT</optional> <replaceable>target</replaceable>;
</synopsis>
where <replaceable>target</replaceable> can be a record variable, a row
@ -1182,8 +1183,8 @@ DELETE ... RETURNING <replaceable>expressions</replaceable> INTO <optional>STRIC
<literal>INTO</literal> clause) just as described above,
and the plan is cached in the same way.
This works for <command>SELECT</command>,
<command>INSERT</command>/<command>UPDATE</command>/<command>DELETE</command> with
<literal>RETURNING</literal>, and certain utility commands
<command>INSERT</command>/<command>UPDATE</command>/<command>DELETE</command>/<command>MERGE</command>
with <literal>RETURNING</literal>, and certain utility commands
that return row sets, such as <command>EXPLAIN</command>.
Except for the <literal>INTO</literal> clause, the SQL command is the same
as it would be written outside <application>PL/pgSQL</application>.
@ -1259,7 +1260,7 @@ END;
</para>
<para>
For <command>INSERT</command>/<command>UPDATE</command>/<command>DELETE</command> with
For <command>INSERT</command>/<command>UPDATE</command>/<command>DELETE</command>/<command>MERGE</command> with
<literal>RETURNING</literal>, <application>PL/pgSQL</application> reports
an error for more than one returned row, even when
<literal>STRICT</literal> is not specified. This is because there
@ -2657,8 +2658,9 @@ $$ LANGUAGE plpgsql;
The <replaceable>query</replaceable> used in this type of <literal>FOR</literal>
statement can be any SQL command that returns rows to the caller:
<command>SELECT</command> is the most common case,
but you can also use <command>INSERT</command>, <command>UPDATE</command>, or
<command>DELETE</command> with a <literal>RETURNING</literal> clause. Some utility
but you can also use <command>INSERT</command>, <command>UPDATE</command>,
<command>DELETE</command>, or <command>MERGE</command> with a
<literal>RETURNING</literal> clause. Some utility
commands such as <command>EXPLAIN</command> will work too.
</para>

View File

@ -2063,9 +2063,10 @@ SELECT <replaceable>select_list</replaceable> FROM <replaceable>table_expression
Table Expressions or <acronym>CTE</acronym>s, can be thought of as defining
temporary tables that exist just for one query. Each auxiliary statement
in a <literal>WITH</literal> clause can be a <command>SELECT</command>,
<command>INSERT</command>, <command>UPDATE</command>, or <command>DELETE</command>; and the
<command>INSERT</command>, <command>UPDATE</command>, <command>DELETE</command>,
or <command>MERGE</command>; and the
<literal>WITH</literal> clause itself is attached to a primary statement that can
be a <command>SELECT</command>, <command>INSERT</command>, <command>UPDATE</command>,
also be a <command>SELECT</command>, <command>INSERT</command>, <command>UPDATE</command>,
<command>DELETE</command>, or <command>MERGE</command>.
</para>
@ -2599,8 +2600,8 @@ SELECT * FROM w AS w1 JOIN w AS w2 ON w1.f = w2.f;
<title>Data-Modifying Statements in <literal>WITH</literal></title>
<para>
You can use most data-modifying statements (<command>INSERT</command>,
<command>UPDATE</command>, or <command>DELETE</command>, but not
You can use data-modifying statements (<command>INSERT</command>,
<command>UPDATE</command>, <command>DELETE</command>, or
<command>MERGE</command>) in <literal>WITH</literal>. This
allows you to perform several different operations in the same query.
An example is:

View File

@ -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>

View File

@ -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>

View File

@ -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>

View File

@ -348,7 +348,7 @@ SELECT m.* FROM some_table, LATERAL myfunc(x) AS m;
column expansion of this kind when it appears at the top level of
a <link linkend="queries-select-lists"><command>SELECT</command> output
list</link>, a <link linkend="dml-returning"><literal>RETURNING</literal>
list</link> in <command>INSERT</command>/<command>UPDATE</command>/<command>DELETE</command>,
list</link> in <command>INSERT</command>/<command>UPDATE</command>/<command>DELETE</command>/<command>MERGE</command>,
a <link linkend="queries-values"><literal>VALUES</literal> clause</link>, or
a <link linkend="sql-syntax-row-constructors">row constructor</link>.
In all other contexts (including when nested inside one of those

View File

@ -301,8 +301,9 @@ SPI_execute("INSERT INTO foo SELECT * FROM bar RETURNING *", false, 5);
is returned in the global variable <varname>SPI_processed</varname>.
If the return value of the function is <symbol>SPI_OK_SELECT</symbol>,
<symbol>SPI_OK_INSERT_RETURNING</symbol>,
<symbol>SPI_OK_DELETE_RETURNING</symbol>, or
<symbol>SPI_OK_UPDATE_RETURNING</symbol>,
<symbol>SPI_OK_DELETE_RETURNING</symbol>,
<symbol>SPI_OK_UPDATE_RETURNING</symbol>, or
<symbol>SPI_OK_MERGE_RETURNING</symbol>,
then you can use the
global pointer <literal>SPITupleTable *SPI_tuptable</literal> to
access the result rows. Some utility commands (such as
@ -473,6 +474,15 @@ typedef struct SPITupleTable
</listitem>
</varlistentry>
<varlistentry>
<term><symbol>SPI_OK_MERGE_RETURNING</symbol></term>
<listitem>
<para>
if a <command>MERGE RETURNING</command> was executed
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><symbol>SPI_OK_UTILITY</symbol></term>
<listitem>

View File

@ -177,7 +177,8 @@
statements separated by semicolons. A semicolon after the last
statement is optional. Unless the function is declared to return
<type>void</type>, the last statement must be a <command>SELECT</command>,
or an <command>INSERT</command>, <command>UPDATE</command>, or <command>DELETE</command>
or an <command>INSERT</command>, <command>UPDATE</command>,
<command>DELETE</command>, or <command>MERGE</command>
that has a <literal>RETURNING</literal> clause.
</para>
@ -1236,8 +1237,9 @@ SELECT x, CASE WHEN x &gt; 0 THEN generate_series(1, 5) ELSE 0 END FROM tab;
<note>
<para>
If a function's last command is <command>INSERT</command>, <command>UPDATE</command>,
or <command>DELETE</command> with <literal>RETURNING</literal>, that command will
If a function's last command is <command>INSERT</command>,
<command>UPDATE</command>, <command>DELETE</command>, or
<command>MERGE</command> with <literal>RETURNING</literal>, that command will
always be executed to completion, even if the function is not declared
with <literal>SETOF</literal> or the calling query does not fetch all the
result rows. Any extra rows produced by the <literal>RETURNING</literal>