mirror of
https://github.com/postgres/postgres.git
synced 2025-12-21 05:21:08 +03:00
Add OLD/NEW support to RETURNING in DML queries.
This allows the RETURNING list of INSERT/UPDATE/DELETE/MERGE queries to explicitly return old and new values by using the special aliases "old" and "new", which are automatically added to the query (if not already defined) while parsing its RETURNING list, allowing things like: RETURNING old.colname, new.colname, ... RETURNING old.*, new.* Additionally, a new syntax is supported, allowing the names "old" and "new" to be changed to user-supplied alias names, e.g.: RETURNING WITH (OLD AS o, NEW AS n) o.colname, n.colname, ... This is useful when the names "old" and "new" are already defined, such as inside trigger functions, allowing backwards compatibility to be maintained -- the interpretation of any existing queries that happen to already refer to relations called "old" or "new", or use those as aliases for other relations, is not changed. For an INSERT, old values will generally be NULL, and for a DELETE, new values will generally be NULL, but that may change for an INSERT with an ON CONFLICT ... DO UPDATE clause, or if a query rewrite rule changes the command type. Therefore, we put no restrictions on the use of old and new in any DML queries. Dean Rasheed, reviewed by Jian He and Jeff Davis. Discussion: https://postgr.es/m/CAEZATCWx0J0-v=Qjc6gXzR=KtsdvAE7Ow=D=mu50AgOe+pvisQ@mail.gmail.com
This commit is contained in:
@@ -25,7 +25,8 @@ 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> ] } [, ...] ]
|
||||
[ RETURNING [ WITH ( { OLD | NEW } AS <replaceable class="parameter">output_alias</replaceable> [, ...] ) ]
|
||||
{ * | <replaceable class="parameter">output_expression</replaceable> [ [ AS ] <replaceable class="parameter">output_name</replaceable> ] } [, ...] ]
|
||||
|
||||
<phrase>where <replaceable class="parameter">data_source</replaceable> is:</phrase>
|
||||
|
||||
@@ -499,6 +500,25 @@ DELETE
|
||||
</listitem>
|
||||
</varlistentry>
|
||||
|
||||
<varlistentry>
|
||||
<term><replaceable class="parameter">output_alias</replaceable></term>
|
||||
<listitem>
|
||||
<para>
|
||||
An optional substitute name for <literal>OLD</literal> or
|
||||
<literal>NEW</literal> rows in the <literal>RETURNING</literal> list.
|
||||
</para>
|
||||
<para>
|
||||
By default, old values from the target table can be returned by writing
|
||||
<literal>OLD.<replaceable class="parameter">column_name</replaceable></literal>
|
||||
or <literal>OLD.*</literal>, and new values can be returned by writing
|
||||
<literal>NEW.<replaceable class="parameter">column_name</replaceable></literal>
|
||||
or <literal>NEW.*</literal>. When an alias is provided, these names are
|
||||
hidden and the old or new rows must be referred to using the alias.
|
||||
For example <literal>RETURNING WITH (OLD AS o, NEW AS n) o.*, n.*</literal>.
|
||||
</para>
|
||||
</listitem>
|
||||
</varlistentry>
|
||||
|
||||
<varlistentry>
|
||||
<term><replaceable class="parameter">output_expression</replaceable></term>
|
||||
<listitem>
|
||||
@@ -517,6 +537,17 @@ DELETE
|
||||
qualifying the <literal>*</literal> with the name or alias of the source
|
||||
or target table.
|
||||
</para>
|
||||
<para>
|
||||
A column name or <literal>*</literal> may also be qualified using
|
||||
<literal>OLD</literal> or <literal>NEW</literal>, or the corresponding
|
||||
<replaceable class="parameter">output_alias</replaceable> for
|
||||
<literal>OLD</literal> or <literal>NEW</literal>, to cause old or new
|
||||
values from the target table to be returned. An unqualified column
|
||||
name from the target table, or a column name or <literal>*</literal>
|
||||
qualified using the target table name or alias will return new values
|
||||
for <literal>INSERT</literal> and <literal>UPDATE</literal> actions, and
|
||||
old values for <literal>DELETE</literal> actions.
|
||||
</para>
|
||||
</listitem>
|
||||
</varlistentry>
|
||||
|
||||
@@ -722,7 +753,7 @@ WHEN MATCHED AND w.stock + s.stock_delta > 0 THEN
|
||||
UPDATE SET stock = w.stock + s.stock_delta
|
||||
WHEN MATCHED THEN
|
||||
DELETE
|
||||
RETURNING merge_action(), w.*;
|
||||
RETURNING merge_action(), w.winename, old.stock AS old_stock, new.stock AS new_stock;
|
||||
</programlisting>
|
||||
|
||||
The <literal>wine_stock_changes</literal> table might be, for example, a
|
||||
|
||||
Reference in New Issue
Block a user