The RETURNING
Clause
A MERGE
statement can contain a RETURNING
clause to return rows added, modified or removed.The merge is executed to completion before rows are returned.The RETURNING
clause can contain any columns from the target table (or updatable view), as well as other columns (eg from the source) and expressions.
The user executing the statement needs to have SELECT
privileges on the columns specified in the RETURNING
clause.
In PSQL, If a RETURNING
clause is present and more than one matching record is found, an error “multiple rows in singleton select” is raised.This behaviour may change in a future Firebird version.
The optional INTO
sub-clause is only valid in PSQL.
Column names can be qualified by the OLD
or NEW
prefix to define exactly what value to return: before or after modification. The returned values include the changes made by BEFORE
triggers.
The syntax of the returning_list is similar to the column list of a SELECT
clause.It is possible to reference all columns using *
, or table_name.*
, NEW.*
and/or OLD.*
.
For the UPDATE
or INSERT
action, unqualified column names, or those qualified by the target table name or alias will behave as if qualified by NEW
, while for the DELETE
action as if qualified by OLD
.
The following example modifies the previous example to affect one line, and adds a RETURNING
clause to return the old and new quantity of goods, and the difference between those values.
MERGE
with a RETURNING
clauseMERGE INTO PRODUCT_INVENTORY AS TARGET
USING (
SELECT
SL.ID_PRODUCT,
SUM(SL.QUANTITY)
FROM SALES_ORDER_LINE SL
JOIN SALES_ORDER S ON S.ID = SL.ID_SALES_ORDER
WHERE S.BYDATE = CURRENT_DATE
AND SL.ID_PRODUCT =: ID_PRODUCT
GROUP BY 1
) AS SRC (ID_PRODUCT, QUANTITY)
ON TARGET.ID_PRODUCT = SRC.ID_PRODUCT
WHEN MATCHED AND TARGET.QUANTITY - SRC.QUANTITY <= 0 THEN
DELETE
WHEN MATCHED THEN
UPDATE SET
TARGET.QUANTITY = TARGET.QUANTITY - SRC.QUANTITY,
TARGET.BYDATE = CURRENT_DATE
RETURNING OLD.QUANTITY, NEW.QUANTITY, SRC.QUANTITY
INTO : OLD_QUANTITY, :NEW_QUANTITY, :DIFF_QUANTITY