3 .\" Author: The PostgreSQL Global Development Group
4 .\" Generator: DocBook XSL Stylesheets vsnapshot <http://docbook.sf.net/>
6 .\" Manual: PostgreSQL 18.0 Documentation
7 .\" Source: PostgreSQL 18.0
10 .TH "MERGE" "7" "2025" "PostgreSQL 18.0" "PostgreSQL 18.0 Documentation"
11 .\" -----------------------------------------------------------------
12 .\" * Define some portability stuff
13 .\" -----------------------------------------------------------------
14 .\" ~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~
15 .\" http://bugs.debian.org/507673
16 .\" http://lists.gnu.org/archive/html/groff/2009-02/msg00013.html
17 .\" ~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~
20 .\" -----------------------------------------------------------------
21 .\" * set default formatting
22 .\" -----------------------------------------------------------------
23 .\" disable hyphenation
25 .\" disable justification (adjust text to left margin only)
27 .\" -----------------------------------------------------------------
28 .\" * MAIN CONTENT STARTS HERE *
29 .\" -----------------------------------------------------------------
31 MERGE \- conditionally insert, update, or delete rows of a table
35 [ WITH \fIwith_query\fR [, \&.\&.\&.] ]
36 MERGE INTO [ ONLY ] \fItarget_table_name\fR [ * ] [ [ AS ] \fItarget_alias\fR ]
37 USING \fIdata_source\fR ON \fIjoin_condition\fR
38 \fIwhen_clause\fR [\&.\&.\&.]
39 [ RETURNING [ WITH ( { OLD | NEW } AS \fIoutput_alias\fR [, \&.\&.\&.] ) ]
40 { * | \fIoutput_expression\fR [ [ AS ] \fIoutput_name\fR ] } [, \&.\&.\&.] ]
42 where \fIdata_source\fR is:
44 { [ ONLY ] \fIsource_table_name\fR [ * ] | ( \fIsource_query\fR ) } [ [ AS ] \fIsource_alias\fR ]
46 and \fIwhen_clause\fR is:
48 { WHEN MATCHED [ AND \fIcondition\fR ] THEN { \fImerge_update\fR | \fImerge_delete\fR | DO NOTHING } |
49 WHEN NOT MATCHED BY SOURCE [ AND \fIcondition\fR ] THEN { \fImerge_update\fR | \fImerge_delete\fR | DO NOTHING } |
50 WHEN NOT MATCHED [ BY TARGET ] [ AND \fIcondition\fR ] THEN { \fImerge_insert\fR | DO NOTHING } }
52 and \fImerge_insert\fR is:
54 INSERT [( \fIcolumn_name\fR [, \&.\&.\&.] )]
55 [ OVERRIDING { SYSTEM | USER } VALUE ]
56 { VALUES ( { \fIexpression\fR | DEFAULT } [, \&.\&.\&.] ) | DEFAULT VALUES }
58 and \fImerge_update\fR is:
60 UPDATE SET { \fIcolumn_name\fR = { \fIexpression\fR | DEFAULT } |
61 ( \fIcolumn_name\fR [, \&.\&.\&.] ) = [ ROW ] ( { \fIexpression\fR | DEFAULT } [, \&.\&.\&.] ) |
62 ( \fIcolumn_name\fR [, \&.\&.\&.] ) = ( \fIsub\-SELECT\fR )
65 and \fImerge_delete\fR is:
72 performs actions that modify rows in the target table identified as
73 \fItarget_table_name\fR, using the
78 statement that can conditionally
83 rows, a task that would otherwise require multiple procedural language statements\&.
87 command performs a join from
89 to the target table producing zero or more candidate change rows\&. For each candidate change row, the status of
91 NOT MATCHED BY SOURCE, or
92 NOT MATCHED [BY TARGET]
93 is set just once, after which
95 clauses are evaluated in the order specified\&. For each candidate change row, the first clause to evaluate as true is executed\&. No more than one
97 clause is executed for any candidate change row\&.
100 actions have the same effect as regular
104 commands of the same names\&. The syntax of those commands is different, notably that there is no
106 clause and no table name is specified\&. All actions refer to the target table, though modifications to other tables may be made using triggers\&.
110 is specified, the source row is skipped\&. Since actions are evaluated in their specified order,
112 can be handy to skip non\-interesting source rows before more fine\-grained handling\&.
118 to compute and return value(s) based on each row inserted, updated, or deleted\&. Any expression using the source or target table\*(Aqs columns, or the
120 function can be computed\&. By default, when an
124 action is performed, the new values of the target table\*(Aqs columns are used, and when a
126 is performed, the old values of the target table\*(Aqs columns are used, but it is also possible to explicitly request old and new values\&. The syntax of the
128 list is identical to that of the output list of
133 privilege\&. If you specify an update action, you must have the
135 privilege on the column(s) of the target table that are referred to in the
137 clause\&. If you specify an insert action, you must have the
139 privilege on the target table\&. If you specify a delete action, you must have the
141 privilege on the target table\&. If you specify a
143 action, you must have the
145 privilege on at least one column of the target table\&. You will also need
147 privilege on any column(s) of the
149 and of the target table referred to in any
153 expression\&. Privileges are tested once at statement start and are checked whether or not particular
155 clauses are executed\&.
158 is not supported if the target table is a materialized view, foreign table, or if it has any rules defined on it\&.
165 clause allows you to specify one or more subqueries that can be referenced by name in the
171 for details\&. Note that
177 \fItarget_table_name\fR
179 The name (optionally schema\-qualified) of the target table or view to merge into\&. If
181 is specified before a table name, matching rows are updated or deleted in the named table only\&. If
183 is not specified, matching rows are also updated or deleted in any tables inheriting from the named table\&. Optionally,
185 can be specified after the table name to explicitly indicate that descendant tables are included\&. The
189 option do not affect insert actions, which always insert into the named table only\&.
192 \fItarget_table_name\fR
193 is a view, it must either be automatically updatable with no
195 triggers, or it must have
197 triggers for every type of action (INSERT,
199 DELETE) specified in the
201 clauses\&. Views with rules are not supported\&.
206 A substitute name for the target table\&. When an alias is provided, it completely hides the actual name of the table\&. For example, given
207 MERGE INTO foo AS f, the remainder of the
209 statement must refer to this table as
215 \fIsource_table_name\fR
217 The name (optionally schema\-qualified) of the source table, view, or transition table\&. If
219 is specified before the table name, matching rows are included from the named table only\&. If
221 is not specified, matching rows are also included from any tables inheriting from the named table\&. Optionally,
223 can be specified after the table name to explicitly indicate that descendant tables are included\&.
228 A query (\fBSELECT\fR
231 statement) that supplies the rows to be merged into the target table\&. Refer to the
235 statement for a description of the syntax\&.
240 A substitute name for the data source\&. When an alias is provided, it completely hides the actual name of the table or the fact that a query was issued\&.
246 is an expression resulting in a value of type
250 clause) that specifies which rows in the
252 match rows in the target table\&.
258 .nr an-no-space-flag 1
265 Only columns from the target table that attempt to match
267 rows should appear in
268 \fIjoin_condition\fR\&.
270 subexpressions that only reference the target table\*(Aqs columns can affect which action is taken, often in surprising ways\&.
273 WHEN NOT MATCHED BY SOURCE
275 WHEN NOT MATCHED [BY TARGET]
276 clauses are specified, the
278 command will perform a
282 and the target table\&. For this to work, at least one
284 subexpression must use an operator that can support a hash join, or all of the subexpressions must use operators that can support a merge join\&.
293 clause is required\&.
299 WHEN NOT MATCHED BY SOURCE, or
300 WHEN NOT MATCHED [BY TARGET]\&. Note that the
302 standard only defines
306 (which is defined to mean no matching target row)\&.
307 WHEN NOT MATCHED BY SOURCE
308 is an extension to the
310 standard, as is the option to append
313 WHEN NOT MATCHED, to make its meaning more explicit\&.
319 and the candidate change row matches a row in the
321 to a row in the target table, the
323 clause is executed if the
325 is absent or it evaluates to
331 WHEN NOT MATCHED BY SOURCE
332 and the candidate change row represents a row in the target table that does not match a row in the
333 \fIdata_source\fR, the
335 clause is executed if the
337 is absent or it evaluates to
343 WHEN NOT MATCHED [BY TARGET]
344 and the candidate change row represents a row in the
346 that does not match a row in the target table, the
348 clause is executed if the
350 is absent or it evaluates to
356 An expression that returns a value of type
357 boolean\&. If this expression for a
360 true, then the action for that clause is executed for that row\&.
364 clause can refer to columns in both the source and the target relations\&. A condition on a
365 WHEN NOT MATCHED BY SOURCE
366 clause can only refer to columns from the target relation, since by definition there is no matching source row\&. A condition on a
367 WHEN NOT MATCHED [BY TARGET]
368 clause can only refer to columns from the source relation, since by definition there is no matching target row\&. Only the system attributes from the target table are accessible\&.
373 The specification of an
375 action that inserts one row into the target table\&. The target column names can be listed in any order\&. If no list of column names is given at all, the default is all the columns of the table in their declared order\&.
377 Each column not present in the explicit or implicit column list will be filled with a default value, either its declared default value or null if there is none\&.
379 If the target table is a partitioned table, each row is routed to the appropriate partition and inserted into it\&. If the target table is a partition, an error will occur if any input row violates the partition constraint\&.
381 Column names may not be specified more than once\&.
383 actions cannot contain sub\-selects\&.
387 clause can be specified\&. The
389 clause can only refer to columns from the source relation, since by definition there is no matching target row\&.
394 The specification of an
396 action that updates the current row of the target table\&. Column names may not be specified more than once\&.
398 Neither a table name nor a
400 clause are allowed\&.
407 action that deletes the current row of the target table\&. Do not include the table name or any other clauses, as you would normally do with a
414 The name of a column in the target table\&. The column name can be qualified with a subfield name or array subscript, if needed\&. (Inserting into only some fields of a composite column leaves the other fields null\&.) Do not include the table\*(Aqs name in the specification of a target column\&.
417 OVERRIDING SYSTEM VALUE
419 Without this clause, it is an error to specify an explicit value (other than
420 DEFAULT) for an identity column defined as
421 GENERATED ALWAYS\&. This clause overrides that restriction\&.
424 OVERRIDING USER VALUE
426 If this clause is specified, then any values supplied for identity columns defined as
428 are ignored and the default sequence\-generated values are applied\&.
433 All columns will be filled with their default values\&. (An
435 clause is not permitted in this form\&.)
440 An expression to assign to the column\&. If used in a
442 clause, the expression can use values from the original row in the target table, and values from the
445 WHEN NOT MATCHED BY SOURCE
446 clause, the expression can only use values from the original row in the target table\&. If used in a
447 WHEN NOT MATCHED [BY TARGET]
448 clause, the expression can only use values from the
455 Set the column to its default value (which will be
457 if no specific default expression has been assigned to it)\&.
464 sub\-query that produces as many output columns as are listed in the parenthesized column list preceding it\&. The sub\-query must yield no more than one row when executed\&. If it yields one row, its column values are assigned to the target columns; if it yields no rows, NULL values are assigned to the target columns\&. If used in a
466 clause, the sub\-query can refer to values from the original row in the target table, and values from the
469 WHEN NOT MATCHED BY SOURCE
470 clause, the sub\-query can only refer to values from the original row in the target table\&.
475 An optional substitute name for
483 By default, old values from the target table can be returned by writing
484 OLD\&.\fIcolumn_name\fR
486 OLD\&.*, and new values can be returned by writing
487 NEW\&.\fIcolumn_name\fR
489 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
490 RETURNING WITH (OLD AS o, NEW AS n) o\&.*, n\&.*\&.
493 \fIoutput_expression\fR
495 An expression to be computed and returned by the
497 command after each row is changed (whether inserted, updated, or deleted)\&. The expression can use any columns of the source or target tables, or the
499 function to return additional information about the action executed\&.
503 will return all columns from the source table, followed by all columns from the target table\&. Often this will lead to a lot of duplication, since it is common for the source and target tables to have a lot of the same columns\&. This can be avoided by qualifying the
505 with the name or alias of the source or target table\&.
509 may also be qualified using
512 NEW, or the corresponding
517 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
519 qualified using the target table name or alias will return new values for
523 actions, and old values for
530 A name to use for a returned column\&.
534 On successful completion, a
536 command returns a command tag of the form
542 MERGE \fItotal_count\fR
550 is the total number of rows changed (whether inserted, updated, or deleted)\&. If
552 is 0, no rows were changed in any way\&.
558 clause, the result will be similar to that of a
560 statement containing the columns and values defined in the
562 list, computed over the row(s) inserted, updated, or deleted by the command\&.
565 The following steps take place during the execution of
578 triggers for all actions specified, whether or not their
591 Perform a join from source to target table\&. The resulting query will be optimized normally and will produce a set of candidate change rows\&. For each candidate change row,
601 Evaluate whether each row is
603 NOT MATCHED BY SOURCE, or
604 NOT MATCHED [BY TARGET]\&.
617 condition in the order specified until one returns true\&.
628 When a condition returns true, perform the following actions:
640 triggers that fire for the action\*(Aqs event type\&.
651 Perform the specified action, invoking any check constraints on the target table\&.
664 triggers that fire for the action\*(Aqs event type\&.
667 If the target relation is a view with
669 triggers for the action\*(Aqs event type, they are used to perform the action instead\&.
683 triggers for actions specified, whether or not they actually occur\&. This is similar to the behavior of an
685 statement that modifies no rows\&.
688 In summary, statement triggers for an event type (say,
689 \fBINSERT\fR) will be fired whenever we
691 an action of that kind\&. In contrast, row\-level triggers will fire only for the specific event type being
692 \fIexecuted\fR\&. So a
694 command might fire statement triggers for both
697 \fBINSERT\fR, even though only
699 row triggers were fired\&.
701 You should ensure that the join produces at most one candidate change row for each target row\&. In other words, a target row shouldn\*(Aqt join to more than one data source row\&. If it does, then only one of the candidate change rows will be used to modify the target row; later attempts to modify the row will cause an error\&. This can also occur if row triggers make changes to the target table and the rows so modified are then subsequently also modified by
702 \fBMERGE\fR\&. If the repeated action is an
703 \fBINSERT\fR, this will cause a uniqueness violation, while a repeated
707 will cause a cardinality violation; the latter behavior is required by the
709 standard\&. This differs from historical
715 statements where second and subsequent attempts to modify the same row are simply ignored\&.
721 sub\-clause, it becomes the final reachable clause of that kind (MATCHED,
722 NOT MATCHED BY SOURCE, or
723 NOT MATCHED [BY TARGET])\&. If a later
725 clause of that kind is specified it would be provably unreachable and an error is raised\&. If no final reachable clause is specified of either kind, it is possible that no action will be taken for a candidate change row\&.
727 The order in which rows are generated from the data source is indeterminate by default\&. A
729 can be used to specify a consistent ordering, if required, which might be needed to avoid deadlocks between concurrent transactions\&.
733 is run concurrently with other commands that modify the target table, the usual transaction isolation rules apply; see
735 for an explanation on the behavior at each isolation level\&. You may also wish to consider using
736 \fBINSERT \&.\&.\&. ON CONFLICT\fR
737 as an alternative statement which offers the ability to run an
741 occurs\&. There are a variety of differences and restrictions between the two statement types and they are not interchangeable\&.
744 Perform maintenance on
747 recent_transactions\&.
753 MERGE INTO customer_account ca
754 USING recent_transactions t
755 ON t\&.customer_id = ca\&.customer_id
757 UPDATE SET balance = balance + transaction_value
758 WHEN NOT MATCHED THEN
759 INSERT (customer_id, balance)
760 VALUES (t\&.customer_id, t\&.transaction_value);
766 Attempt to insert a new stock item along with the quantity of stock\&. If the item already exists, instead update the stock count of the existing item\&. Don\*(Aqt allow entries that have zero stock\&. Return details of all changes made\&.
773 USING wine_stock_changes s
774 ON s\&.winename = w\&.winename
775 WHEN NOT MATCHED AND s\&.stock_delta > 0 THEN
776 INSERT VALUES(s\&.winename, s\&.stock_delta)
777 WHEN MATCHED AND w\&.stock + s\&.stock_delta > 0 THEN
778 UPDATE SET stock = w\&.stock + s\&.stock_delta
781 RETURNING merge_action(), w\&.winename, old\&.stock AS old_stock, new\&.stock AS new_stock;
789 table might be, for example, a temporary table recently loaded into the database\&.
793 based on a replacement wine list, inserting rows for any new stock, updating modified stock entries, and deleting any wines not present in the new list\&.
800 USING new_wine_list s
801 ON s\&.winename = w\&.winename
802 WHEN NOT MATCHED BY TARGET THEN
803 INSERT VALUES(s\&.winename, s\&.stock)
804 WHEN MATCHED AND w\&.stock != s\&.stock THEN
805 UPDATE SET stock = s\&.stock
806 WHEN NOT MATCHED BY SOURCE THEN
815 This command conforms to the
830 clause are extensions to the