Repair memory leaks in plpython.
[pgsql.git] / doc / src / sgml / ref / merge.sgml
blobd80a5c5cc9b5a87ab5e3fe9a74f03e92c519659d
1 <!--
2 doc/src/sgml/ref/merge.sgml
3 PostgreSQL documentation
4 -->
6 <refentry id="sql-merge">
7 <indexterm zone="sql-merge">
8 <primary>MERGE</primary>
9 </indexterm>
11 <refmeta>
12 <refentrytitle>MERGE</refentrytitle>
13 <manvolnum>7</manvolnum>
14 <refmiscinfo>SQL - Language Statements</refmiscinfo>
15 </refmeta>
17 <refnamediv>
18 <refname>MERGE</refname>
19 <refpurpose>conditionally insert, update, or delete rows of a table</refpurpose>
20 </refnamediv>
22 <refsynopsisdiv>
23 <synopsis>
24 [ WITH <replaceable class="parameter">with_query</replaceable> [, ...] ]
25 MERGE INTO [ ONLY ] <replaceable class="parameter">target_table_name</replaceable> [ * ] [ [ AS ] <replaceable class="parameter">target_alias</replaceable> ]
26 USING <replaceable class="parameter">data_source</replaceable> ON <replaceable class="parameter">join_condition</replaceable>
27 <replaceable class="parameter">when_clause</replaceable> [...]
28 [ RETURNING { * | <replaceable class="parameter">output_expression</replaceable> [ [ AS ] <replaceable class="parameter">output_name</replaceable> ] } [, ...] ]
30 <phrase>where <replaceable class="parameter">data_source</replaceable> is:</phrase>
32 { [ ONLY ] <replaceable class="parameter">source_table_name</replaceable> [ * ] | ( <replaceable class="parameter">source_query</replaceable> ) } [ [ AS ] <replaceable class="parameter">source_alias</replaceable> ]
34 <phrase>and <replaceable class="parameter">when_clause</replaceable> is:</phrase>
36 { WHEN MATCHED [ AND <replaceable class="parameter">condition</replaceable> ] THEN { <replaceable class="parameter">merge_update</replaceable> | <replaceable class="parameter">merge_delete</replaceable> | DO NOTHING } |
37 WHEN NOT MATCHED BY SOURCE [ AND <replaceable class="parameter">condition</replaceable> ] THEN { <replaceable class="parameter">merge_update</replaceable> | <replaceable class="parameter">merge_delete</replaceable> | DO NOTHING } |
38 WHEN NOT MATCHED [ BY TARGET ] [ AND <replaceable class="parameter">condition</replaceable> ] THEN { <replaceable class="parameter">merge_insert</replaceable> | DO NOTHING } }
40 <phrase>and <replaceable class="parameter">merge_insert</replaceable> is:</phrase>
42 INSERT [( <replaceable class="parameter">column_name</replaceable> [, ...] )]
43 [ OVERRIDING { SYSTEM | USER } VALUE ]
44 { VALUES ( { <replaceable class="parameter">expression</replaceable> | DEFAULT } [, ...] ) | DEFAULT VALUES }
46 <phrase>and <replaceable class="parameter">merge_update</replaceable> is:</phrase>
48 UPDATE SET { <replaceable class="parameter">column_name</replaceable> = { <replaceable class="parameter">expression</replaceable> | DEFAULT } |
49 ( <replaceable class="parameter">column_name</replaceable> [, ...] ) = [ ROW ] ( { <replaceable class="parameter">expression</replaceable> | DEFAULT } [, ...] ) |
50 ( <replaceable class="parameter">column_name</replaceable> [, ...] ) = ( <replaceable class="parameter">sub-SELECT</replaceable> )
51 } [, ...]
53 <phrase>and <replaceable class="parameter">merge_delete</replaceable> is:</phrase>
55 DELETE
56 </synopsis>
57 </refsynopsisdiv>
59 <refsect1>
60 <title>Description</title>
62 <para>
63 <command>MERGE</command> performs actions that modify rows in the
64 target table identified as <replaceable class="parameter">target_table_name</replaceable>,
65 using the <replaceable class="parameter">data_source</replaceable>.
66 <command>MERGE</command> provides a single <acronym>SQL</acronym>
67 statement that can conditionally <command>INSERT</command>,
68 <command>UPDATE</command> or <command>DELETE</command> rows, a task
69 that would otherwise require multiple procedural language statements.
70 </para>
72 <para>
73 First, the <command>MERGE</command> command performs a join
74 from <replaceable class="parameter">data_source</replaceable> to
75 the target table
76 producing zero or more candidate change rows. For each candidate change
77 row, the status of <literal>MATCHED</literal>,
78 <literal>NOT MATCHED BY SOURCE</literal>,
79 or <literal>NOT MATCHED [BY TARGET]</literal>
80 is set just once, after which <literal>WHEN</literal> clauses are evaluated
81 in the order specified. For each candidate change row, the first clause to
82 evaluate as true is executed. No more than one <literal>WHEN</literal>
83 clause is executed for any candidate change row.
84 </para>
86 <para>
87 <command>MERGE</command> actions have the same effect as
88 regular <command>UPDATE</command>, <command>INSERT</command>, or
89 <command>DELETE</command> commands of the same names. The syntax of
90 those commands is different, notably that there is no <literal>WHERE</literal>
91 clause and no table name is specified. All actions refer to the
92 target table,
93 though modifications to other tables may be made using triggers.
94 </para>
96 <para>
97 When <literal>DO NOTHING</literal> is specified, the source row is
98 skipped. Since actions are evaluated in their specified order, <literal>DO
99 NOTHING</literal> can be handy to skip non-interesting source rows before
100 more fine-grained handling.
101 </para>
103 <para>
104 The optional <literal>RETURNING</literal> clause causes <command>MERGE</command>
105 to compute and return value(s) based on each row inserted, updated, or
106 deleted. Any expression using the source or target table's columns, or
107 the <link linkend="merge-action"><function>merge_action()</function></link>
108 function can be computed. When an <command>INSERT</command> or
109 <command>UPDATE</command> action is performed, the new values of the target
110 table's columns are used. When a <command>DELETE</command> is performed,
111 the old values of the target table's columns are used. The syntax of the
112 <literal>RETURNING</literal> list is identical to that of the output list
113 of <command>SELECT</command>.
114 </para>
116 <para>
117 There is no separate <literal>MERGE</literal> privilege.
118 If you specify an update action, you must have the
119 <literal>UPDATE</literal> privilege on the column(s)
120 of the target table
121 that are referred to in the <literal>SET</literal> clause.
122 If you specify an insert action, you must have the <literal>INSERT</literal>
123 privilege on the target table.
124 If you specify a delete action, you must have the <literal>DELETE</literal>
125 privilege on the target table.
126 If you specify a <literal>DO NOTHING</literal> action, you must have
127 the <literal>SELECT</literal> privilege on at least one column
128 of the target table.
129 You will also need <literal>SELECT</literal> privilege on any column(s)
130 of the <replaceable class="parameter">data_source</replaceable> and
131 of the target table referred to
132 in any <literal>condition</literal> (including <literal>join_condition</literal>)
133 or <literal>expression</literal>.
134 Privileges are tested once at statement start and are checked
135 whether or not particular <literal>WHEN</literal> clauses are executed.
136 </para>
138 <para>
139 <command>MERGE</command> is not supported if the
140 target table is a
141 materialized view, foreign table, or if it has any
142 rules defined on it.
143 </para>
144 </refsect1>
146 <refsect1>
147 <title>Parameters</title>
149 <variablelist>
150 <varlistentry>
151 <term><replaceable class="parameter">with_query</replaceable></term>
152 <listitem>
153 <para>
154 The <literal>WITH</literal> clause allows you to specify one or more
155 subqueries that can be referenced by name in the <command>MERGE</command>
156 query. See <xref linkend="queries-with"/> and <xref linkend="sql-select"/>
157 for details. Note that <literal>WITH RECURSIVE</literal> is not supported
158 by <command>MERGE</command>.
159 </para>
160 </listitem>
161 </varlistentry>
163 <varlistentry>
164 <term><replaceable class="parameter">target_table_name</replaceable></term>
165 <listitem>
166 <para>
167 The name (optionally schema-qualified) of the target table or view to
168 merge into. If <literal>ONLY</literal> is specified before a table
169 name, matching rows are updated or deleted in the named table only. If
170 <literal>ONLY</literal> is not specified, matching rows are also updated
171 or deleted in any tables inheriting from the named table. Optionally,
172 <literal>*</literal> can be specified after the table name to explicitly
173 indicate that descendant tables are included. The
174 <literal>ONLY</literal> keyword and <literal>*</literal> option do not
175 affect insert actions, which always insert into the named table only.
176 </para>
178 <para>
179 If <replaceable class="parameter">target_table_name</replaceable> is a
180 view, it must either be automatically updatable with no
181 <literal>INSTEAD OF</literal> triggers, or it must have
182 <literal>INSTEAD OF</literal> triggers for every type of action
183 (<literal>INSERT</literal>, <literal>UPDATE</literal>, and
184 <literal>DELETE</literal>) specified in the <literal>WHEN</literal>
185 clauses. Views with rules are not supported.
186 </para>
187 </listitem>
188 </varlistentry>
190 <varlistentry>
191 <term><replaceable class="parameter">target_alias</replaceable></term>
192 <listitem>
193 <para>
194 A substitute name for the target table. When an alias is
195 provided, it completely hides the actual name of the table. For
196 example, given <literal>MERGE INTO foo AS f</literal>, the remainder of the
197 <command>MERGE</command> statement must refer to this table as
198 <literal>f</literal> not <literal>foo</literal>.
199 </para>
200 </listitem>
201 </varlistentry>
203 <varlistentry>
204 <term><replaceable class="parameter">source_table_name</replaceable></term>
205 <listitem>
206 <para>
207 The name (optionally schema-qualified) of the source table, view, or
208 transition table. If <literal>ONLY</literal> is specified before the
209 table name, matching rows are included from the named table only. If
210 <literal>ONLY</literal> is not specified, matching rows are also included
211 from any tables inheriting from the named table. Optionally,
212 <literal>*</literal> can be specified after the table name to explicitly
213 indicate that descendant tables are included.
214 </para>
215 </listitem>
216 </varlistentry>
218 <varlistentry>
219 <term><replaceable class="parameter">source_query</replaceable></term>
220 <listitem>
221 <para>
222 A query (<command>SELECT</command> statement or <command>VALUES</command>
223 statement) that supplies the rows to be merged into the
224 target table.
225 Refer to the <xref linkend="sql-select"/>
226 statement or <xref linkend="sql-values"/>
227 statement for a description of the syntax.
228 </para>
229 </listitem>
230 </varlistentry>
232 <varlistentry>
233 <term><replaceable class="parameter">source_alias</replaceable></term>
234 <listitem>
235 <para>
236 A substitute name for the data source. When an alias is
237 provided, it completely hides the actual name of the table or the fact
238 that a query was issued.
239 </para>
240 </listitem>
241 </varlistentry>
243 <varlistentry>
244 <term><replaceable class="parameter">join_condition</replaceable></term>
245 <listitem>
246 <para>
247 <replaceable class="parameter">join_condition</replaceable> is
248 an expression resulting in a value of type
249 <type>boolean</type> (similar to a <literal>WHERE</literal>
250 clause) that specifies which rows in the
251 <replaceable class="parameter">data_source</replaceable>
252 match rows in the target table.
253 </para>
254 <warning>
255 <para>
256 Only columns from the target table
257 that attempt to match <replaceable class="parameter">data_source</replaceable>
258 rows should appear in <replaceable class="parameter">join_condition</replaceable>.
259 <replaceable class="parameter">join_condition</replaceable> subexpressions that
260 only reference the target table's
261 columns can affect which action is taken, often in surprising ways.
262 </para>
263 <para>
264 If both <literal>WHEN NOT MATCHED BY SOURCE</literal> and
265 <literal>WHEN NOT MATCHED [BY TARGET]</literal> clauses are specified,
266 the <command>MERGE</command> command will perform a <literal>FULL</literal>
267 join between <replaceable class="parameter">data_source</replaceable>
268 and the target table. For this to work, at least one
269 <replaceable class="parameter">join_condition</replaceable> subexpression
270 must use an operator that can support a hash join, or all of the
271 subexpressions must use operators that can support a merge join.
272 </para>
273 </warning>
274 </listitem>
275 </varlistentry>
277 <varlistentry>
278 <term><replaceable class="parameter">when_clause</replaceable></term>
279 <listitem>
280 <para>
281 At least one <literal>WHEN</literal> clause is required.
282 </para>
283 <para>
284 The <literal>WHEN</literal> clause may specify <literal>WHEN MATCHED</literal>,
285 <literal>WHEN NOT MATCHED BY SOURCE</literal>, or
286 <literal>WHEN NOT MATCHED [BY TARGET]</literal>.
287 Note that the <acronym>SQL</acronym> standard only defines
288 <literal>WHEN MATCHED</literal> and <literal>WHEN NOT MATCHED</literal>
289 (which is defined to mean no matching target row).
290 <literal>WHEN NOT MATCHED BY SOURCE</literal> is an extension to the
291 <acronym>SQL</acronym> standard, as is the option to append
292 <literal>BY TARGET</literal> to <literal>WHEN NOT MATCHED</literal>, to
293 make its meaning more explicit.
294 </para>
295 <para>
296 If the <literal>WHEN</literal> clause specifies <literal>WHEN MATCHED</literal>
297 and the candidate change row matches a row in the
298 <replaceable class="parameter">data_source</replaceable> to a row in the
299 target table, the <literal>WHEN</literal> clause is executed if the
300 <replaceable class="parameter">condition</replaceable> is
301 absent or it evaluates to <literal>true</literal>.
302 </para>
303 <para>
304 If the <literal>WHEN</literal> clause specifies
305 <literal>WHEN NOT MATCHED BY SOURCE</literal> and the candidate change
306 row represents a row in the target table that does not match a row in the
307 <replaceable class="parameter">data_source</replaceable>, the
308 <literal>WHEN</literal> clause is executed if the
309 <replaceable class="parameter">condition</replaceable> is
310 absent or it evaluates to <literal>true</literal>.
311 </para>
312 <para>
313 If the <literal>WHEN</literal> clause specifies
314 <literal>WHEN NOT MATCHED [BY TARGET]</literal> and the candidate change
315 row represents a row in the
316 <replaceable class="parameter">data_source</replaceable> that does not
317 match a row in the target table,
318 the <literal>WHEN</literal> clause is executed if the
319 <replaceable class="parameter">condition</replaceable> is
320 absent or it evaluates to <literal>true</literal>.
321 </para>
322 </listitem>
323 </varlistentry>
325 <varlistentry>
326 <term><replaceable class="parameter">condition</replaceable></term>
327 <listitem>
328 <para>
329 An expression that returns a value of type <type>boolean</type>.
330 If this expression for a <literal>WHEN</literal> clause
331 returns <literal>true</literal>, then the action for that clause
332 is executed for that row.
333 </para>
334 <para>
335 A condition on a <literal>WHEN MATCHED</literal> clause can refer to columns
336 in both the source and the target relations. A condition on a
337 <literal>WHEN NOT MATCHED BY SOURCE</literal> clause can only refer to
338 columns from the target relation, since by definition there is no matching
339 source row. A condition on a <literal>WHEN NOT MATCHED [BY TARGET]</literal>
340 clause can only refer to columns from
341 the source relation, since by definition there is no matching target row.
342 Only the system attributes from the target table are accessible.
343 </para>
344 </listitem>
345 </varlistentry>
347 <varlistentry>
348 <term><replaceable class="parameter">merge_insert</replaceable></term>
349 <listitem>
350 <para>
351 The specification of an <literal>INSERT</literal> action that inserts
352 one row into the target table.
353 The target column names can be listed in any order. If no list of
354 column names is given at all, the default is all the columns of the
355 table in their declared order.
356 </para>
357 <para>
358 Each column not present in the explicit or implicit column list will be
359 filled with a default value, either its declared default value
360 or null if there is none.
361 </para>
362 <para>
363 If the target table
364 is a partitioned table, each row is routed to the appropriate partition
365 and inserted into it.
366 If the target table
367 is a partition, an error will occur if any input row violates the
368 partition constraint.
369 </para>
370 <para>
371 Column names may not be specified more than once.
372 <command>INSERT</command> actions cannot contain sub-selects.
373 </para>
374 <para>
375 Only one <literal>VALUES</literal> clause can be specified.
376 The <literal>VALUES</literal> clause can only refer to columns from
377 the source relation, since by definition there is no matching target row.
378 </para>
379 </listitem>
380 </varlistentry>
382 <varlistentry>
383 <term><replaceable class="parameter">merge_update</replaceable></term>
384 <listitem>
385 <para>
386 The specification of an <literal>UPDATE</literal> action that updates
387 the current row of the target table.
388 Column names may not be specified more than once.
389 </para>
390 <para>
391 Neither a table name nor a <literal>WHERE</literal> clause are allowed.
392 </para>
393 </listitem>
394 </varlistentry>
396 <varlistentry>
397 <term><replaceable class="parameter">merge_delete</replaceable></term>
398 <listitem>
399 <para>
400 Specifies a <literal>DELETE</literal> action that deletes the current row
401 of the target table.
402 Do not include the table name or any other clauses, as you would normally
403 do with a <xref linkend="sql-delete"/> command.
404 </para>
405 </listitem>
406 </varlistentry>
408 <varlistentry>
409 <term><replaceable class="parameter">column_name</replaceable></term>
410 <listitem>
411 <para>
412 The name of a column in the target table. The column name
413 can be qualified with a subfield name or array subscript, if
414 needed. (Inserting into only some fields of a composite
415 column leaves the other fields null.)
416 Do not include the table's name in the specification
417 of a target column.
418 </para>
419 </listitem>
420 </varlistentry>
422 <varlistentry>
423 <term><literal>OVERRIDING SYSTEM VALUE</literal></term>
424 <listitem>
425 <para>
426 Without this clause, it is an error to specify an explicit value
427 (other than <literal>DEFAULT</literal>) for an identity column defined
428 as <literal>GENERATED ALWAYS</literal>. This clause overrides that
429 restriction.
430 </para>
431 </listitem>
432 </varlistentry>
434 <varlistentry>
435 <term><literal>OVERRIDING USER VALUE</literal></term>
436 <listitem>
437 <para>
438 If this clause is specified, then any values supplied for identity
439 columns defined as <literal>GENERATED BY DEFAULT</literal> are ignored
440 and the default sequence-generated values are applied.
441 </para>
442 </listitem>
443 </varlistentry>
445 <varlistentry>
446 <term><literal>DEFAULT VALUES</literal></term>
447 <listitem>
448 <para>
449 All columns will be filled with their default values.
450 (An <literal>OVERRIDING</literal> clause is not permitted in this
451 form.)
452 </para>
453 </listitem>
454 </varlistentry>
456 <varlistentry>
457 <term><replaceable class="parameter">expression</replaceable></term>
458 <listitem>
459 <para>
460 An expression to assign to the column. If used in a
461 <literal>WHEN MATCHED</literal> clause, the expression can use values
462 from the original row in the target table, and values from the
463 <replaceable class="parameter">data_source</replaceable> row.
464 If used in a <literal>WHEN NOT MATCHED BY SOURCE</literal> clause, the
465 expression can only use values from the original row in the target table.
466 If used in a <literal>WHEN NOT MATCHED [BY TARGET]</literal> clause, the
467 expression can only use values from the
468 <replaceable class="parameter">data_source</replaceable> row.
469 </para>
470 </listitem>
471 </varlistentry>
473 <varlistentry>
474 <term><literal>DEFAULT</literal></term>
475 <listitem>
476 <para>
477 Set the column to its default value (which will be <literal>NULL</literal>
478 if no specific default expression has been assigned to it).
479 </para>
480 </listitem>
481 </varlistentry>
483 <varlistentry>
484 <term><replaceable class="parameter">sub-SELECT</replaceable></term>
485 <listitem>
486 <para>
487 A <literal>SELECT</literal> sub-query that produces as many output columns
488 as are listed in the parenthesized column list preceding it. The
489 sub-query must yield no more than one row when executed. If it
490 yields one row, its column values are assigned to the target columns;
491 if it yields no rows, NULL values are assigned to the target columns.
492 If used in a <literal>WHEN MATCHED</literal> clause, the sub-query can
493 refer to values from the original row in the target table, and values
494 from the <replaceable class="parameter">data_source</replaceable> row.
495 If used in a <literal>WHEN NOT MATCHED BY SOURCE</literal> clause, the
496 sub-query can only refer to values from the original row in the target
497 table.
498 </para>
499 </listitem>
500 </varlistentry>
502 <varlistentry>
503 <term><replaceable class="parameter">output_expression</replaceable></term>
504 <listitem>
505 <para>
506 An expression to be computed and returned by the <command>MERGE</command>
507 command after each row is changed (whether inserted, updated, or deleted).
508 The expression can use any columns of the source or target tables, or the
509 <link linkend="merge-action"><function>merge_action()</function></link>
510 function to return additional information about the action executed.
511 </para>
512 <para>
513 Writing <literal>*</literal> will return all columns from the source
514 table, followed by all columns from the target table. Often this will
515 lead to a lot of duplication, since it is common for the source and
516 target tables to have a lot of the same columns. This can be avoided by
517 qualifying the <literal>*</literal> with the name or alias of the source
518 or target table.
519 </para>
520 </listitem>
521 </varlistentry>
523 <varlistentry>
524 <term><replaceable class="parameter">output_name</replaceable></term>
525 <listitem>
526 <para>
527 A name to use for a returned column.
528 </para>
529 </listitem>
530 </varlistentry>
532 </variablelist>
533 </refsect1>
535 <refsect1>
536 <title>Outputs</title>
538 <para>
539 On successful completion, a <command>MERGE</command> command returns a command
540 tag of the form
541 <screen>
542 MERGE <replaceable class="parameter">total_count</replaceable>
543 </screen>
544 The <replaceable class="parameter">total_count</replaceable> is the total
545 number of rows changed (whether inserted, updated, or deleted).
546 If <replaceable class="parameter">total_count</replaceable> is 0, no rows
547 were changed in any way.
548 </para>
550 <para>
551 If the <command>MERGE</command> command contains a <literal>RETURNING</literal>
552 clause, the result will be similar to that of a <command>SELECT</command>
553 statement containing the columns and values defined in the
554 <literal>RETURNING</literal> list, computed over the row(s) inserted, updated,
555 or deleted by the command.
556 </para>
557 </refsect1>
559 <refsect1>
560 <title>Notes</title>
562 <para>
563 The following steps take place during the execution of
564 <command>MERGE</command>.
565 <orderedlist>
566 <listitem>
567 <para>
568 Perform any <literal>BEFORE STATEMENT</literal> triggers for all
569 actions specified, whether or not their <literal>WHEN</literal>
570 clauses match.
571 </para>
572 </listitem>
573 <listitem>
574 <para>
575 Perform a join from source to target table.
576 The resulting query will be optimized normally and will produce
577 a set of candidate change rows. For each candidate change row,
578 <orderedlist>
579 <listitem>
580 <para>
581 Evaluate whether each row is <literal>MATCHED</literal>,
582 <literal>NOT MATCHED BY SOURCE</literal>, or
583 <literal>NOT MATCHED [BY TARGET]</literal>.
584 </para>
585 </listitem>
586 <listitem>
587 <para>
588 Test each <literal>WHEN</literal> condition in the order
589 specified until one returns true.
590 </para>
591 </listitem>
592 <listitem>
593 <para>
594 When a condition returns true, perform the following actions:
595 <orderedlist>
596 <listitem>
597 <para>
598 Perform any <literal>BEFORE ROW</literal> triggers that fire
599 for the action's event type.
600 </para>
601 </listitem>
602 <listitem>
603 <para>
604 Perform the specified action, invoking any check constraints on the
605 target table.
606 </para>
607 </listitem>
608 <listitem>
609 <para>
610 Perform any <literal>AFTER ROW</literal> triggers that fire for
611 the action's event type.
612 </para>
613 </listitem>
614 </orderedlist>
615 If the target relation is a view with <literal>INSTEAD OF ROW</literal>
616 triggers for the action's event type, they are used to perform the
617 action instead.
618 </para>
619 </listitem>
620 </orderedlist></para>
621 </listitem>
622 <listitem>
623 <para>
624 Perform any <literal>AFTER STATEMENT</literal> triggers for actions
625 specified, whether or not they actually occur. This is similar to the
626 behavior of an <command>UPDATE</command> statement that modifies no rows.
627 </para>
628 </listitem>
629 </orderedlist>
630 In summary, statement triggers for an event type (say,
631 <command>INSERT</command>) will be fired whenever we
632 <emphasis>specify</emphasis> an action of that kind.
633 In contrast, row-level triggers will fire only for the specific event type
634 being <emphasis>executed</emphasis>.
635 So a <command>MERGE</command> command might fire statement triggers for both
636 <command>UPDATE</command> and <command>INSERT</command>, even though only
637 <command>UPDATE</command> row triggers were fired.
638 </para>
640 <para>
641 You should ensure that the join produces at most one candidate change row
642 for each target row. In other words, a target row shouldn't join to more
643 than one data source row. If it does, then only one of the candidate change
644 rows will be used to modify the target row; later attempts to modify the
645 row will cause an error.
646 This can also occur if row triggers make changes to the target table
647 and the rows so modified are then subsequently also modified by
648 <command>MERGE</command>.
649 If the repeated action is an <command>INSERT</command>, this will
650 cause a uniqueness violation, while a repeated <command>UPDATE</command>
651 or <command>DELETE</command> will cause a cardinality violation; the
652 latter behavior is required by the <acronym>SQL</acronym> standard.
653 This differs from historical <productname>PostgreSQL</productname>
654 behavior of joins in <command>UPDATE</command> and
655 <command>DELETE</command> statements where second and subsequent
656 attempts to modify the same row are simply ignored.
657 </para>
659 <para>
660 If a <literal>WHEN</literal> clause omits an <literal>AND</literal>
661 sub-clause, it becomes the final reachable clause of that
662 kind (<literal>MATCHED</literal>, <literal>NOT MATCHED BY SOURCE</literal>,
663 or <literal>NOT MATCHED [BY TARGET]</literal>).
664 If a later <literal>WHEN</literal> clause of that kind
665 is specified it would be provably unreachable and an error is raised.
666 If no final reachable clause is specified of either kind, it is
667 possible that no action will be taken for a candidate change row.
668 </para>
670 <para>
671 The order in which rows are generated from the data source is
672 indeterminate by default.
673 A <replaceable class="parameter">source_query</replaceable> can be
674 used to specify a consistent ordering, if required, which might be
675 needed to avoid deadlocks between concurrent transactions.
676 </para>
678 <para>
679 When <command>MERGE</command> is run concurrently with other commands
680 that modify the target table, the usual transaction isolation rules
681 apply; see <xref linkend="transaction-iso"/> for an explanation
682 on the behavior at each isolation level.
683 You may also wish to consider using <command>INSERT ... ON CONFLICT</command>
684 as an alternative statement which offers the ability to run an
685 <command>UPDATE</command> if a concurrent <command>INSERT</command>
686 occurs. There are a variety of differences and restrictions between
687 the two statement types and they are not interchangeable.
688 </para>
689 </refsect1>
691 <refsect1>
692 <title>Examples</title>
694 <para>
695 Perform maintenance on <literal>customer_accounts</literal> based
696 upon new <literal>recent_transactions</literal>.
698 <programlisting>
699 MERGE INTO customer_account ca
700 USING recent_transactions t
701 ON t.customer_id = ca.customer_id
702 WHEN MATCHED THEN
703 UPDATE SET balance = balance + transaction_value
704 WHEN NOT MATCHED THEN
705 INSERT (customer_id, balance)
706 VALUES (t.customer_id, t.transaction_value);
707 </programlisting>
708 </para>
710 <para>
711 Attempt to insert a new stock item along with the quantity of stock. If
712 the item already exists, instead update the stock count of the existing
713 item. Don't allow entries that have zero stock. Return details of all
714 changes made.
715 <programlisting>
716 MERGE INTO wines w
717 USING wine_stock_changes s
718 ON s.winename = w.winename
719 WHEN NOT MATCHED AND s.stock_delta > 0 THEN
720 INSERT VALUES(s.winename, s.stock_delta)
721 WHEN MATCHED AND w.stock + s.stock_delta > 0 THEN
722 UPDATE SET stock = w.stock + s.stock_delta
723 WHEN MATCHED THEN
724 DELETE
725 RETURNING merge_action(), w.*;
726 </programlisting>
728 The <literal>wine_stock_changes</literal> table might be, for example, a
729 temporary table recently loaded into the database.
730 </para>
732 <para>
733 Update <literal>wines</literal> based on a replacement wine list, inserting
734 rows for any new stock, updating modified stock entries, and deleting any
735 wines not present in the new list.
736 <programlisting>
737 MERGE INTO wines w
738 USING new_wine_list s
739 ON s.winename = w.winename
740 WHEN NOT MATCHED BY TARGET THEN
741 INSERT VALUES(s.winename, s.stock)
742 WHEN MATCHED AND w.stock != s.stock THEN
743 UPDATE SET stock = s.stock
744 WHEN NOT MATCHED BY SOURCE THEN
745 DELETE;
746 </programlisting>
747 </para>
749 </refsect1>
751 <refsect1>
752 <title>Compatibility</title>
753 <para>
754 This command conforms to the <acronym>SQL</acronym> standard.
755 </para>
756 <para>
757 The <literal>WITH</literal> clause, <literal>BY SOURCE</literal> and
758 <literal>BY TARGET</literal> qualifiers to
759 <literal>WHEN NOT MATCHED</literal>, <literal>DO NOTHING</literal> action,
760 and <literal>RETURNING</literal> clause are extensions to the
761 <acronym>SQL</acronym> standard.
762 </para>
763 </refsect1>
764 </refentry>