MERGE INTO
Merges a set of updates, insertions, and deletions based on a source table into a target Delta table.
This statement is supported only for Delta Lake tables.
Syntax
MERGE INTO target_table_name [target_alias]
USING source_table_reference [source_alias]
ON merge_condition
[ WHEN MATCHED [ AND condition ] THEN matched_action ] [...]
[ WHEN NOT MATCHED [ AND condition ] THEN not_matched_action ] [...]
matched_action
{ DELETE |
UPDATE SET * |
UPDATE SET { column1 = value1 } [, ...] }
not_matched_action
{ INSERT * |
INSERT (column1 [, ...] ) VALUES (value1 [, ...])
Parameters
-
A Table name identifying the table being modified. The table referenced must be a Delta table.
-
A Table aliasfor the target table. The alias must not include a column list.
-
A Table name identifying the source table to be merged into the target table.
-
A Table alias for the source table. The alias must not include a column list.
-
How the rows from one relation are combined with the rows of another relation. An expression with a return type of BOOLEAN.
-
A Boolean expression which must be
true
to satisfy theWHEN MATCHED
orWHEN NOT MATCHED
clause. matched_action
There can be any number of
WHEN MATCHED
andWHEN NOT MATCHED
clauses each, but at least one clause is required. Multiple matches are allowed when matches are unconditionally deleted (since unconditional delete is not ambiguous even if there are multiple matches).WHEN MATCHED
clauses are executed when a source row matches a target table row based on the match condition. These clauses have the following semantics.WHEN MATCHED
clauses can have at most oneUPDATE
and oneDELETE
action. TheUPDATE
action inmerge
only updates the specified columns of the matched target row. TheDELETE
action will delete the matched row.Each
WHEN MATCHED
clause can have an optional condition. If this clause condition exists, theUPDATE
orDELETE
action is executed for any matching source-target row pair row only when the clause condition is true.If there are multiple
WHEN MATCHED
clauses, then they are evaluated in the order they are specified. AllWHEN MATCHED
clauses, except the last one, must have conditions.If none of the
WHEN MATCHED
conditions evaluate to true for a source and target row pair that matches the merge condition, then the target row is left unchanged.To update all the columns of the target Delta table with the corresponding columns of the source dataset, use
UPDATE SET *
. This is equivalent toUPDATE SET col1 = source.col1 [, col2 = source.col2 ...]
for all the columns of the target Delta table. Therefore, this action assumes that the source table has the same columns as those in the target table, otherwise the query will throw an analysis error.This behavior changes when automatic schema migration is enabled. See Automatic schema evolution for details.
WHEN NOT MATCHED
clauses are executed when a source row does not match any target row based on the match condition. These clauses have the following semantics.WHEN NOT MATCHED
clauses can only have theINSERT
action. The new row is generated based on the specified column and corresponding expressions. All the columns in the target table do not need to be specified. For unspecified target columns,NULL
is inserted.Each
WHEN NOT MATCHED
clause can have an optional condition. If the clause condition is present, a source row is inserted only if that condition is true for that row. Otherwise, the source row is ignored.If there are multiple
WHEN NOT MATCHED
clauses, then they are evaluated in the order they are specified. AllWHEN NOT MATCHED
clauses, except the last one, must have conditions.To insert all the columns of the target Delta table with the corresponding columns of the source dataset, use
INSERT *
. This is equivalent toINSERT (col1 [, col2 ...]) VALUES (source.col1 [, source.col2 ...])
for all the columns of the target Delta table. Therefore, this action assumes that the source table has the same columns as those in the target table, otherwise the query will throw an analysis error.Note
This behavior changes when automatic schema migration is enabled. See Automatic schema evolution for details.
Important
A MERGE
operation can fail if multiple rows of the source dataset match and attempt to update the same rows of the target Delta table. According to the SQL semantics of merge, such an update operation is ambiguous as it is unclear which source row should be used to update the matched target row. You can preprocess the source table to eliminate the possibility of multiple matches. See the Change data capture example—it preprocesses the change dataset (that is, the source dataset) to retain only the latest change for each key before applying that change into the target Delta table.
Examples
You can use MERGE INTO
for complex operations like deduplicating data, upserting change data, applying SCD Type 2 operations, etc. See Merge examples for a few examples.
Related articles
Feedback
Submit and view feedback for