6.6. MERGE
Merges data from a source set into a target table or updatable view
Syntax
MERGE INTO target [[AS] target_alias]
USING <table-reference>
ON <join_condition>
<merge_when> [<merge_when> ...]
[PLAN <plan-expr>]
[ORDER BY <ordering-list>]
[RETURNING <returning_list> [INTO <variables>]]
<merge_when> ::=
<merge_when_matched>
| <merge_when_not_matched_target>
| <merge_when_not_matched_source>
<merge_when_matched> ::=
WHEN MATCHED [AND <condition>] THEN
{ UPDATE SET <assignment-list>
| DELETE }
<merge_when_not_matched_target> ::=
WHEN NOT MATCHED [BY TARGET] [AND <condition>] THEN
INSERT [( <column_list> )] [<override_opt>]
VALUES ( <value_list> )
<merge_when_not_matched_source> ::=
WHEN NOT MATCHED BY SOURCE [ AND <condition> ] THEN
{ UPDATE SET <assignment-list>
| DELETE }
<table-reference> ::= <table-primary> | <joined-table>
<table-primary> ::=
<table-or-query-name> [[AS] correlation-name]
| [LATERAL] <derived-table> [<correlation-or-recognition>]
| <parenthesized-joined-table>
<assignment_list ::=
col_name = <m_value> [, <col_name> = <m_value> ...]]
<override_opt> ::=
OVERRIDING {USER | SYSTEM} VALUE
<column_list> ::= colname [, colname ...]
<value_list> ::= <m_value> [, <m_value> ...]
<m_value> ::= <value-expression> | DEFAULT
<returning_list> ::= * | <output_column> [, <output_column]
<output_column> ::=
target.* | NEW.* | OLD.*
| <return_expression> [COLLATE collation] [[AS] alias]
<return_expression> ::=
<value-expression>
| [target.]col_name
| NEW.col_name
| OLD.col_name
<value-expression> ::=
<literal>
| <context-variable>
| any other expression returning a single
value of a Firebird data type or NULL
<variables> ::=
[:]varname [, [:]varname ...]
MERGE Statement Parameters| Argument | Description |
|---|---|
target | Name of target relation (table or updatable view) |
table-reference | Data source. It can be a table, a view, a stored procedure, a derived table or a parenthesized joined table |
target_alias | Alias for the target relation (table or updatable view) |
join_conditions | The ( |
condition | Additional test condition in |
col_name | Name of a column in the target relation |
value-expression | The value assigned to a column in the target table. This expression may be a literal value, a PSQL variable, a column from the source, or a compatible context variable |
return_expression | The expression to be returned in the |
ret_alias | Alias for the value expression in the |
varname | Name of a PSQL local variable |
The MERGE statement merges records from a source <table-reference> into a target table or updatable view.
The source may be a table, view or anything you can
in general.
Each source record will be used to update one or more target records, insert a new record in the target table, delete a record from the target table or do nothing.SELECT from
The action taken depends on the supplied join condition, the WHEN clause(s), and the — optional — condition in the WHEN clause.
The join condition and condition in the WHEN will typically contain a comparison of fields in the source and target relations.
Multiple WHEN MATCHED and WHEN NOT MATCHED clauses are allowed.
For each row in the source, the WHEN clauses are checked in the order they are specified in the statement.
If the condition in the WHEN clause does not evaluate to true, the clause is skipped, and the next clause will be checked.
This will be done until the condition for a WHEN clause evaluates to true, or a WHEN clauses without condition matches, or there are no more WHEN clauses.
If a matching clause is found, the action associated with the clause is executed.
For each row in the source, at most one action is executed.
If the WHEN MATCHED clause is present, and several records match a single record in the target table, an error is raised.
Contrary to the other WHEN clauses, the WHEN NOT MATCHED BY SOURCE clauses evaluates records in the target which match no record in source.
At least one WHEN clause must be present.
WHEN NOT MATCHED is evaluated from the source viewpoint, that is, the table or set specified in USING.
It has to work this way because if the source record does not match a target record, INSERT is executed.
Of course, if there is a target record which does not match a source record, nothing is done.
Currently, in PSQL, the ROW_COUNT variable returns the value 1, even if more than one record is modified or inserted.
For details and progress, refer to firebird#4722.
6.6.1. The ORDER BY Clause
The ORDER BY can be used to influence the order in which rows are evaluated.
The primary use case is when combined with RETURNING, to influence the order rows are returned.
6.6.2. 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.
Using MERGE with a RETURNING clause
MERGE 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
6.6.3. Examples of MERGE
Update books when present, or add new record if absent
MERGE INTO books bUSING purchases pON p.title = b.title and p.type = 'bk'WHEN MATCHED THENUPDATE SET b.desc = b.desc || '; ' || p.descWHEN NOT MATCHED THENINSERT (title, desc, bought) values (p.title, p.desc, p.bought);Using a derived table
MERGE INTO customers cUSING (SELECT * from customers_delta WHERE id > 10) cdON (c.id = cd.id)WHEN MATCHED THENUPDATE SET name = cd.nameWHEN NOT MATCHED THENINSERT (id, name) values (cd.id, cd.name);Together with a recursive CTE
MERGE INTO numbersUSING (WITH RECURSIVE r(n) AS (SELECT 1 FROM rdb$databaseUNION ALLSELECT n+1 FROM r WHERE n < 200)SELECT n FROM r) tON numbers.num = t.nWHEN NOT MATCHED THENINSERT(num) VALUES(t.n);Using
DELETEclauseMERGE INTO SALARY_HISTORYUSING (SELECT EMP_NOFROM EMPLOYEEWHERE DEPT_NO = 120) EMPON SALARY_HISTORY.EMP_NO = EMP.EMP_NOWHEN MATCHED THEN DELETEThe following example updates the
PRODUCT_INVENTORYtable daily based on orders processed in theSALES_ORDER_LINEtable. If the stock level of the product would drop to zero or lower, then the row for that product is removed from thePRODUCT_INVENTORYtable.MERGE INTO PRODUCT_INVENTORY AS TARGETUSING (SELECTSL.ID_PRODUCT,SUM (SL.QUANTITY)FROM SALES_ORDER_LINE SLJOIN SALES_ORDER S ON S.ID = SL.ID_SALES_ORDERWHERE S.BYDATE = CURRENT_DATEGROUP BY 1) AS SRC (ID_PRODUCT, QUANTITY)ON TARGET.ID_PRODUCT = SRC.ID_PRODUCTWHEN MATCHED AND TARGET.QUANTITY - SRC.QUANTITY <= 0 THENDELETEWHEN MATCHED THENUPDATE SETTARGET.QUANTITY = TARGET.QUANTITY - SRC.QUANTITY,TARGET.BYDATE = CURRENT_DATE
See alsoSection 6.1, “SELECT”, Section 6.2, “INSERT”, Section 6.3, “UPDATE”, Section 6.4, “UPDATE OR INSERT”, Section 6.5, “DELETE”