From 80feb727c869cc0b2e12bd1543bafa449be9c8e2 Mon Sep 17 00:00:00 2001 From: Dean Rasheed Date: Thu, 16 Jan 2025 14:57:35 +0000 Subject: 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 --- doc/src/sgml/dml.sgml | 41 +++++++++++++++++++++++++++++---- doc/src/sgml/ref/delete.sgml | 40 +++++++++++++++++++++++++++++++- doc/src/sgml/ref/insert.sgml | 54 +++++++++++++++++++++++++++++++++++++++++++- doc/src/sgml/ref/merge.sgml | 35 ++++++++++++++++++++++++++-- doc/src/sgml/ref/update.sgml | 38 ++++++++++++++++++++++++++++--- doc/src/sgml/rules.sgml | 17 ++++++++++++++ 6 files changed, 214 insertions(+), 11 deletions(-) (limited to 'doc/src') diff --git a/doc/src/sgml/dml.sgml b/doc/src/sgml/dml.sgml index 3d95bdb94e7..458aee788b7 100644 --- a/doc/src/sgml/dml.sgml +++ b/doc/src/sgml/dml.sgml @@ -308,7 +308,8 @@ DELETE FROM products; - In an INSERT, the data available to RETURNING is + In an INSERT, the default data available to + RETURNING is the row as it was inserted. This is not so useful in trivial inserts, since it would just repeat the data provided by the client. But it can be very handy when relying on computed default values. For example, @@ -325,7 +326,8 @@ INSERT INTO users (firstname, lastname) VALUES ('Joe', 'Cool') RETURNING id; - In an UPDATE, the data available to RETURNING is + In an UPDATE, the default data available to + RETURNING is the new content of the modified row. For example: UPDATE products SET price = price * 1.10 @@ -335,7 +337,8 @@ UPDATE products SET price = price * 1.10 - In a DELETE, the data available to RETURNING is + In a DELETE, the default data available to + RETURNING is the content of the deleted row. For example: DELETE FROM products @@ -345,7 +348,8 @@ DELETE FROM products - In a MERGE, the data available to RETURNING is + In a MERGE, the default data available to + RETURNING 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 RETURNING * @@ -359,6 +363,35 @@ MERGE INTO products p USING new_products n ON p.product_no = n.product_no + + In each of these commands, it is also possible to explicitly return the + old and new content of the modified row. For example: + +UPDATE products SET price = price * 1.10 + WHERE price <= 99.99 + RETURNING name, old.price AS old_price, new.price AS new_price, + new.price - old.price AS price_change; + + In this example, writing new.price is the same as + just writing price, but it makes the meaning clearer. + + + + This syntax for returning old and new values is available in + INSERT, UPDATE, + DELETE, and MERGE commands, but + typically old values will be NULL for an + INSERT, and new values will be NULL + for a DELETE. However, there are situations where it + can still be useful for those commands. For example, in an + INSERT with an + ON CONFLICT DO UPDATE + clause, the old values will be non-NULL for conflicting + rows. Similarly, if a DELETE is turned into an + UPDATE by a rewrite rule, + the new values may be non-NULL. + + If there are triggers () on the target table, the data available to RETURNING is the row as modified by diff --git a/doc/src/sgml/ref/delete.sgml b/doc/src/sgml/ref/delete.sgml index 7717855bc9e..29649f6afd6 100644 --- a/doc/src/sgml/ref/delete.sgml +++ b/doc/src/sgml/ref/delete.sgml @@ -25,7 +25,8 @@ PostgreSQL documentation DELETE FROM [ ONLY ] table_name [ * ] [ [ AS ] alias ] [ USING from_item [, ...] ] [ WHERE condition | WHERE CURRENT OF cursor_name ] - [ RETURNING { * | output_expression [ [ AS ] output_name ] } [, ...] ] + [ RETURNING [ WITH ( { OLD | NEW } AS output_alias [, ...] ) ] + { * | output_expression [ [ AS ] output_name ] } [, ...] ] @@ -160,6 +161,26 @@ DELETE FROM [ ONLY ] table_name [ * + + output_alias + + + An optional substitute name for OLD or + NEW rows in the RETURNING list. + + + + By default, old values from the target table can be returned by writing + OLD.column_name + or OLD.*, and new values can be returned by writing + NEW.column_name + or NEW.*. When an alias is provided, these names are + hidden and the old or new rows must be referred to using the alias. + For example RETURNING WITH (OLD AS o, NEW AS n) o.*, n.*. + + + + output_expression @@ -170,6 +191,23 @@ DELETE FROM [ ONLY ] table_name [ * or table(s) listed in USING. Write * to return all columns. + + + A column name or * may be qualified using + OLD or NEW, or the corresponding + output_alias for + OLD or NEW, to cause old or new + values to be returned. An unqualified column name, or + *, or a column name or * qualified + using the target table name or alias will return old values. + + + + For a simple DELETE, all new values will be + NULL. However, if an ON DELETE + rule causes an INSERT or UPDATE + to be executed instead, the new values may be non-NULL. + diff --git a/doc/src/sgml/ref/insert.sgml b/doc/src/sgml/ref/insert.sgml index 6f0adee1a12..3f139917790 100644 --- a/doc/src/sgml/ref/insert.sgml +++ b/doc/src/sgml/ref/insert.sgml @@ -26,7 +26,8 @@ INSERT INTO table_name [ AS expression | DEFAULT } [, ...] ) [, ...] | query } [ ON CONFLICT [ conflict_target ] conflict_action ] - [ RETURNING { * | output_expression [ [ AS ] output_name ] } [, ...] ] + [ RETURNING [ WITH ( { OLD | NEW } AS output_alias [, ...] ) ] + { * | output_expression [ [ AS ] output_name ] } [, ...] ] where conflict_target can be one of: @@ -293,6 +294,26 @@ INSERT INTO table_name [ AS + + output_alias + + + An optional substitute name for OLD or + NEW rows in the RETURNING list. + + + + By default, old values from the target table can be returned by writing + OLD.column_name + or OLD.*, and new values can be returned by writing + NEW.column_name + or NEW.*. When an alias is provided, these names are + hidden and the old or new rows must be referred to using the alias. + For example RETURNING WITH (OLD AS o, NEW AS n) o.*, n.*. + + + + output_expression @@ -305,6 +326,23 @@ INSERT INTO table_name [ AS * to return all columns of the inserted or updated row(s). + + + A column name or * may be qualified using + OLD or NEW, or the corresponding + output_alias for + OLD or NEW, to cause old or new + values to be returned. An unqualified column name, or + *, or a column name or * + qualified using the target table name or alias will return new values. + + + + For a simple INSERT, all old values will be + NULL. However, for an INSERT + with an ON CONFLICT DO UPDATE clause, the old + values may be non-NULL. + @@ -711,6 +749,20 @@ INSERT INTO employees_log SELECT *, current_timestamp FROM upd; INSERT INTO distributors (did, dname) VALUES (5, 'Gizmo Transglobal'), (6, 'Associated Computing, Inc') ON CONFLICT (did) DO UPDATE SET dname = EXCLUDED.dname; + + + + Insert or update new distributors as above, returning information + about any existing values that were updated, together with the new data + inserted. Note that the returned values for old_did + and old_dname will be NULL for + non-conflicting rows: + +INSERT INTO distributors (did, dname) + VALUES (5, 'Gizmo Transglobal'), (6, 'Associated Computing, Inc') + ON CONFLICT (did) DO UPDATE SET dname = EXCLUDED.dname + RETURNING old.did AS old_did, old.dname AS old_dname, + new.did AS new_did, new.dname AS new_dname; diff --git a/doc/src/sgml/ref/merge.sgml b/doc/src/sgml/ref/merge.sgml index d80a5c5cc9b..ecbcd8345d8 100644 --- a/doc/src/sgml/ref/merge.sgml +++ b/doc/src/sgml/ref/merge.sgml @@ -25,7 +25,8 @@ PostgreSQL documentation MERGE INTO [ ONLY ] target_table_name [ * ] [ [ AS ] target_alias ] USING data_source ON join_condition when_clause [...] -[ RETURNING { * | output_expression [ [ AS ] output_name ] } [, ...] ] +[ RETURNING [ WITH ( { OLD | NEW } AS output_alias [, ...] ) ] + { * | output_expression [ [ AS ] output_name ] } [, ...] ] where data_source is: @@ -499,6 +500,25 @@ DELETE + + output_alias + + + An optional substitute name for OLD or + NEW rows in the RETURNING list. + + + By default, old values from the target table can be returned by writing + OLD.column_name + or OLD.*, and new values can be returned by writing + NEW.column_name + or NEW.*. When an alias is provided, these names are + hidden and the old or new rows must be referred to using the alias. + For example RETURNING WITH (OLD AS o, NEW AS n) o.*, n.*. + + + + output_expression @@ -517,6 +537,17 @@ DELETE qualifying the * with the name or alias of the source or target table. + + A column name or * may also be qualified using + OLD or NEW, or the corresponding + output_alias for + OLD or NEW, 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 * + qualified using the target table name or alias will return new values + for INSERT and UPDATE actions, and + old values for DELETE actions. + @@ -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; The wine_stock_changes table might be, for example, a diff --git a/doc/src/sgml/ref/update.sgml b/doc/src/sgml/ref/update.sgml index 1c433bec2bb..12ec5ba0709 100644 --- a/doc/src/sgml/ref/update.sgml +++ b/doc/src/sgml/ref/update.sgml @@ -29,7 +29,8 @@ UPDATE [ ONLY ] table_name [ * ] [ } [, ...] [ FROM from_item [, ...] ] [ WHERE condition | WHERE CURRENT OF cursor_name ] - [ RETURNING { * | output_expression [ [ AS ] output_name ] } [, ...] ] + [ RETURNING [ WITH ( { OLD | NEW } AS output_alias [, ...] ) ] + { * | output_expression [ [ AS ] output_name ] } [, ...] ] @@ -211,6 +212,26 @@ UPDATE [ ONLY ] table_name [ * ] [ + + output_alias + + + An optional substitute name for OLD or + NEW rows in the RETURNING list. + + + + By default, old values from the target table can be returned by writing + OLD.column_name + or OLD.*, and new values can be returned by writing + NEW.column_name + or NEW.*. When an alias is provided, these names are + hidden and the old or new rows must be referred to using the alias. + For example RETURNING WITH (OLD AS o, NEW AS n) o.*, n.*. + + + + output_expression @@ -221,6 +242,16 @@ UPDATE [ ONLY ] table_name [ * ] [ or table(s) listed in FROM. Write * to return all columns. + + + A column name or * may be qualified using + OLD or NEW, or the corresponding + output_alias for + OLD or NEW, to cause old or new + values to be returned. An unqualified column name, or + *, or a column name or * qualified + using the target table name or alias will return new values. + @@ -348,12 +379,13 @@ UPDATE weather SET temp_lo = temp_lo+1, temp_hi = temp_lo+15, prcp = DEFAULT - Perform the same operation and return the updated entries: + Perform the same operation and return the updated entries, and the old + precipitation value: UPDATE weather SET temp_lo = temp_lo+1, temp_hi = temp_lo+15, prcp = DEFAULT WHERE city = 'San Francisco' AND date = '2003-07-03' - RETURNING temp_lo, temp_hi, prcp; + RETURNING temp_lo, temp_hi, prcp, old.prcp AS old_prcp; diff --git a/doc/src/sgml/rules.sgml b/doc/src/sgml/rules.sgml index 7e98f5694b4..9fdf8b1d917 100644 --- a/doc/src/sgml/rules.sgml +++ b/doc/src/sgml/rules.sgml @@ -1645,6 +1645,23 @@ CREATE RULE shoelace_ins AS ON INSERT TO shoelace RETURNING clause is simply ignored for INSERT. + + Note that in the RETURNING clause of a rule, + OLD and NEW refer to the + pseudorelations added as extra range table entries to the rewritten + query, rather than old/new rows in the result relation. Thus, for + example, in a rule supporting UPDATE queries on this + view, if the RETURNING clause contained + old.sl_name, the old name would always be returned, + regardless of whether the RETURNING clause in the + query on the view specified OLD or NEW, + which might be confusing. To avoid this confusion, and support returning + old and new values in queries on the view, the RETURNING + clause in the rule definition should refer to entries from the result + relation such as shoelace_data.sl_name, without + specifying OLD or NEW. + + Now assume that once in a while, a pack of shoelaces arrives at the shop and a big parts list along with it. But you don't want -- cgit v1.2.3