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