mirror of https://github.com/postgres/postgres
MERGE performs actions that modify rows in the target table using a source table or query. MERGE provides a single SQL statement that can conditionally INSERT/UPDATE/DELETE rows -- a task that would otherwise require multiple PL statements. For example, MERGE INTO target AS t USING source AS s ON t.tid = s.sid WHEN MATCHED AND t.balance > s.delta THEN UPDATE SET balance = t.balance - s.delta WHEN MATCHED THEN DELETE WHEN NOT MATCHED AND s.delta > 0 THEN INSERT VALUES (s.sid, s.delta) WHEN NOT MATCHED THEN DO NOTHING; MERGE works with regular tables, partitioned tables and inheritance hierarchies, including column and row security enforcement, as well as support for row and statement triggers and transition tables therein. MERGE is optimized for OLTP and is parameterizable, though also useful for large scale ETL/ELT. MERGE is not intended to be used in preference to existing single SQL commands for INSERT, UPDATE or DELETE since there is some overhead. MERGE can be used from PL/pgSQL. MERGE does not support targetting updatable views or foreign tables, and RETURNING clauses are not allowed either. These limitations are likely fixable with sufficient effort. Rewrite rules are also not supported, but it's not clear that we'd want to support them. Author: Pavan Deolasee <pavan.deolasee@gmail.com> Author: Álvaro Herrera <alvherre@alvh.no-ip.org> Author: Amit Langote <amitlangote09@gmail.com> Author: Simon Riggs <simon.riggs@enterprisedb.com> Reviewed-by: Peter Eisentraut <peter.eisentraut@enterprisedb.com> Reviewed-by: Andres Freund <andres@anarazel.de> (earlier versions) Reviewed-by: Peter Geoghegan <pg@bowt.ie> (earlier versions) Reviewed-by: Robert Haas <robertmhaas@gmail.com> (earlier versions) Reviewed-by: Japin Li <japinli@hotmail.com> Reviewed-by: Justin Pryzby <pryzby@telsasoft.com> Reviewed-by: Tomas Vondra <tomas.vondra@enterprisedb.com> Reviewed-by: Zhihong Yu <zyu@yugabyte.com> Discussion: https://postgr.es/m/CANP8+jKitBSrB7oTgT9CY2i1ObfOt36z0XMraQc+Xrz8QB0nXA@mail.gmail.com Discussion: https://postgr.es/m/CAH2-WzkJdBuxj9PO=2QaO9-3h3xGbQPZ34kJH=HukRekwM-GZg@mail.gmail.com Discussion: https://postgr.es/m/20201231134736.GA25392@alvherre.pgsqlpull/81/head
parent
ae63017bdb
commit
7103ebb7aa
@ -0,0 +1,620 @@ |
||||
<!-- |
||||
doc/src/sgml/ref/merge.sgml |
||||
PostgreSQL documentation |
||||
--> |
||||
|
||||
<refentry id="sql-merge"> |
||||
|
||||
<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 <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> [...] |
||||
|
||||
<phrase>where <replaceable class="parameter">data_source</replaceable> is</phrase> |
||||
|
||||
{ <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 [ 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> [, ...] ) = ( { <replaceable class="parameter">expression</replaceable> | DEFAULT } [, ...] ) } [, ...] |
||||
|
||||
<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 |
||||
<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 |
||||
<replaceable class="parameter">target_table_name</replaceable> |
||||
producing zero or more candidate change rows. For each candidate change |
||||
row, the status of <literal>MATCHED</literal> or <literal>NOT MATCHED</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 |
||||
<replaceable class="parameter">target_table_name</replaceable>, |
||||
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> |
||||
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 <replaceable class="parameter">target_table_name</replaceable> |
||||
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 <replaceable class="parameter">target_table_name</replaceable>. |
||||
If you specify an delete action, you must have the <literal>DELETE</literal> |
||||
privilege on the <replaceable class="parameter">target_table_name</replaceable>. |
||||
Privileges are tested once at statement start and are checked |
||||
whether or not particular <literal>WHEN</literal> clauses are executed. |
||||
You will require the <literal>SELECT</literal> privilege on the |
||||
<replaceable class="parameter">data_source</replaceable> and any column(s) |
||||
of the <replaceable class="parameter">target_table_name</replaceable> |
||||
referred to in a <literal>condition</literal>. |
||||
</para> |
||||
|
||||
<para> |
||||
<command>MERGE</command> is not supported if the |
||||
<replaceable class="parameter">target_table_name</replaceable> 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">target_table_name</replaceable></term> |
||||
<listitem> |
||||
<para> |
||||
The name (optionally schema-qualified) of the target table to merge into. |
||||
</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. |
||||
</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 |
||||
<replaceable class="parameter">target_table_name</replaceable>. |
||||
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 |
||||
<replaceable class="parameter">target_table_name</replaceable>. |
||||
</para> |
||||
<warning> |
||||
<para> |
||||
Only columns from <replaceable class="parameter">target_table_name</replaceable> |
||||
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 <replaceable class="parameter">target_table_name</replaceable> |
||||
columns can affect which action is taken, often in surprising ways. |
||||
</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> |
||||
If the <literal>WHEN</literal> clause specifies <literal>WHEN MATCHED</literal> |
||||
and the candidate change row matches a row in the |
||||
<replaceable class="parameter">target_table_name</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> |
||||
Conversely, if the <literal>WHEN</literal> clause specifies |
||||
<literal>WHEN NOT MATCHED</literal> |
||||
and the candidate change row does not match a row in the |
||||
<replaceable class="parameter">target_table_name</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> |
||||
</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</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 expression for any column is not of the correct data type, |
||||
automatic type conversion will be attempted. |
||||
</para> |
||||
<para> |
||||
If <replaceable class="parameter">target_table_name</replaceable> |
||||
is a partitioned table, each row is routed to the appropriate partition |
||||
and inserted into it. |
||||
If <replaceable class="parameter">target_table_name</replaceable> |
||||
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 <replaceable class="parameter">target_table_name</replaceable>. |
||||
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 <replaceable class="parameter">target_table_name</replaceable>. |
||||
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 <replaceable |
||||
class="parameter">target_table_name</replaceable>. 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 |
||||
<literal>data_source</literal> row. |
||||
If used in a <literal>WHEN NOT MATCHED</literal> clause, the |
||||
expression can use values from the <literal>data_source</literal>. |
||||
</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">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. |
||||
</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> |
||||
|
||||
</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> or |
||||
<literal>NOT MATCHED</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> |
||||
</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> or <literal>NOT MATCHED</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> |
||||
There is no <literal>RETURNING</literal> clause with |
||||
<command>MERGE</command>. Actions of <command>INSERT</command>, |
||||
<command>UPDATE</command> and <command>DELETE</command> cannot contain |
||||
<literal>RETURNING</literal> or <literal>WITH</literal> clauses. |
||||
</para> |
||||
|
||||
<para> |
||||
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>CustomerAccounts</literal> based |
||||
upon new <literal>Transactions</literal>. |
||||
|
||||
<programlisting> |
||||
MERGE INTO CustomerAccount CA |
||||
USING RecentTransactions T |
||||
ON T.CustomerId = CA.CustomerId |
||||
WHEN MATCHED THEN |
||||
UPDATE SET Balance = Balance + TransactionValue |
||||
WHEN NOT MATCHED THEN |
||||
INSERT (CustomerId, Balance) |
||||
VALUES (T.CustomerId, T.TransactionValue); |
||||
</programlisting> |
||||
</para> |
||||
|
||||
<para> |
||||
Notice that this would be exactly equivalent to the following |
||||
statement because the <literal>MATCHED</literal> result does not change |
||||
during execution. |
||||
|
||||
<programlisting> |
||||
MERGE INTO CustomerAccount CA |
||||
USING (Select CustomerId, TransactionValue From RecentTransactions) AS T |
||||
ON CA.CustomerId = T.CustomerId |
||||
WHEN NOT MATCHED THEN |
||||
INSERT (CustomerId, Balance) |
||||
VALUES (T.CustomerId, T.TransactionValue) |
||||
WHEN MATCHED THEN |
||||
UPDATE SET Balance = Balance + TransactionValue; |
||||
</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. |
||||
<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; |
||||
</programlisting> |
||||
|
||||
The <literal>wine_stock_changes</literal> table might be, for example, a |
||||
temporary table recently loaded into the database. |
||||
</para> |
||||
|
||||
</refsect1> |
||||
|
||||
<refsect1> |
||||
<title>Compatibility</title> |
||||
<para> |
||||
This command conforms to the <acronym>SQL</acronym> standard. |
||||
</para> |
||||
<para> |
||||
The WITH clause and <literal>DO NOTHING</literal> action are extensions to |
||||
the <acronym>SQL</acronym> standard. |
||||
</para> |
||||
</refsect1> |
||||
</refentry> |
File diff suppressed because it is too large
Load Diff
@ -0,0 +1,415 @@ |
||||
/*-------------------------------------------------------------------------
|
||||
* |
||||
* parse_merge.c |
||||
* handle merge-statement in parser |
||||
* |
||||
* Portions Copyright (c) 1996-2022, PostgreSQL Global Development Group |
||||
* Portions Copyright (c) 1994, Regents of the University of California |
||||
* |
||||
* |
||||
* IDENTIFICATION |
||||
* src/backend/parser/parse_merge.c |
||||
* |
||||
*------------------------------------------------------------------------- |
||||
*/ |
||||
|
||||
#include "postgres.h" |
||||
|
||||
#include "access/sysattr.h" |
||||
#include "miscadmin.h" |
||||
#include "nodes/makefuncs.h" |
||||
#include "nodes/nodeFuncs.h" |
||||
#include "parser/analyze.h" |
||||
#include "parser/parse_collate.h" |
||||
#include "parser/parsetree.h" |
||||
#include "parser/parser.h" |
||||
#include "parser/parse_clause.h" |
||||
#include "parser/parse_cte.h" |
||||
#include "parser/parse_expr.h" |
||||
#include "parser/parse_merge.h" |
||||
#include "parser/parse_relation.h" |
||||
#include "parser/parse_target.h" |
||||
#include "utils/rel.h" |
||||
#include "utils/relcache.h" |
||||
|
||||
static void setNamespaceForMergeWhen(ParseState *pstate, |
||||
MergeWhenClause *mergeWhenClause, |
||||
Index targetRTI, |
||||
Index sourceRTI); |
||||
static void setNamespaceVisibilityForRTE(List *namespace, RangeTblEntry *rte, |
||||
bool rel_visible, |
||||
bool cols_visible); |
||||
|
||||
/*
|
||||
* Make appropriate changes to the namespace visibility while transforming |
||||
* individual action's quals and targetlist expressions. In particular, for |
||||
* INSERT actions we must only see the source relation (since INSERT action is |
||||
* invoked for NOT MATCHED tuples and hence there is no target tuple to deal |
||||
* with). On the other hand, UPDATE and DELETE actions can see both source and |
||||
* target relations. |
||||
* |
||||
* Also, since the internal join node can hide the source and target |
||||
* relations, we must explicitly make the respective relation as visible so |
||||
* that columns can be referenced unqualified from these relations. |
||||
*/ |
||||
static void |
||||
setNamespaceForMergeWhen(ParseState *pstate, MergeWhenClause *mergeWhenClause, |
||||
Index targetRTI, Index sourceRTI) |
||||
{ |
||||
RangeTblEntry *targetRelRTE, |
||||
*sourceRelRTE; |
||||
|
||||
targetRelRTE = rt_fetch(targetRTI, pstate->p_rtable); |
||||
sourceRelRTE = rt_fetch(sourceRTI, pstate->p_rtable); |
||||
|
||||
if (mergeWhenClause->matched) |
||||
{ |
||||
Assert(mergeWhenClause->commandType == CMD_UPDATE || |
||||
mergeWhenClause->commandType == CMD_DELETE || |
||||
mergeWhenClause->commandType == CMD_NOTHING); |
||||
|
||||
/* MATCHED actions can see both target and source relations. */ |
||||
setNamespaceVisibilityForRTE(pstate->p_namespace, |
||||
targetRelRTE, true, true); |
||||
setNamespaceVisibilityForRTE(pstate->p_namespace, |
||||
sourceRelRTE, true, true); |
||||
} |
||||
else |
||||
{ |
||||
/*
|
||||
* NOT MATCHED actions can't see target relation, but they can see |
||||
* source relation. |
||||
*/ |
||||
Assert(mergeWhenClause->commandType == CMD_INSERT || |
||||
mergeWhenClause->commandType == CMD_NOTHING); |
||||
setNamespaceVisibilityForRTE(pstate->p_namespace, |
||||
targetRelRTE, false, false); |
||||
setNamespaceVisibilityForRTE(pstate->p_namespace, |
||||
sourceRelRTE, true, true); |
||||
} |
||||
} |
||||
|
||||
/*
|
||||
* transformMergeStmt - |
||||
* transforms a MERGE statement |
||||
*/ |
||||
Query * |
||||
transformMergeStmt(ParseState *pstate, MergeStmt *stmt) |
||||
{ |
||||
Query *qry = makeNode(Query); |
||||
ListCell *l; |
||||
AclMode targetPerms = ACL_NO_RIGHTS; |
||||
bool is_terminal[2]; |
||||
Index sourceRTI; |
||||
List *mergeActionList; |
||||
Node *joinExpr; |
||||
ParseNamespaceItem *nsitem; |
||||
|
||||
/* There can't be any outer WITH to worry about */ |
||||
Assert(pstate->p_ctenamespace == NIL); |
||||
|
||||
qry->commandType = CMD_MERGE; |
||||
qry->hasRecursive = false; |
||||
|
||||
/* process the WITH clause independently of all else */ |
||||
if (stmt->withClause) |
||||
{ |
||||
if (stmt->withClause->recursive) |
||||
ereport(ERROR, |
||||
(errcode(ERRCODE_SYNTAX_ERROR), |
||||
errmsg("WITH RECURSIVE is not supported for MERGE statement"))); |
||||
|
||||
qry->cteList = transformWithClause(pstate, stmt->withClause); |
||||
qry->hasModifyingCTE = pstate->p_hasModifyingCTE; |
||||
} |
||||
|
||||
/*
|
||||
* Check WHEN clauses for permissions and sanity |
||||
*/ |
||||
is_terminal[0] = false; |
||||
is_terminal[1] = false; |
||||
foreach(l, stmt->mergeWhenClauses) |
||||
{ |
||||
MergeWhenClause *mergeWhenClause = (MergeWhenClause *) lfirst(l); |
||||
int when_type = (mergeWhenClause->matched ? 0 : 1); |
||||
|
||||
/*
|
||||
* Collect action types so we can check target permissions |
||||
*/ |
||||
switch (mergeWhenClause->commandType) |
||||
{ |
||||
case CMD_INSERT: |
||||
targetPerms |= ACL_INSERT; |
||||
break; |
||||
case CMD_UPDATE: |
||||
targetPerms |= ACL_UPDATE; |
||||
break; |
||||
case CMD_DELETE: |
||||
targetPerms |= ACL_DELETE; |
||||
break; |
||||
case CMD_NOTHING: |
||||
break; |
||||
default: |
||||
elog(ERROR, "unknown action in MERGE WHEN clause"); |
||||
} |
||||
|
||||
/*
|
||||
* Check for unreachable WHEN clauses |
||||
*/ |
||||
if (mergeWhenClause->condition == NULL) |
||||
is_terminal[when_type] = true; |
||||
else if (is_terminal[when_type]) |
||||
ereport(ERROR, |
||||
(errcode(ERRCODE_SYNTAX_ERROR), |
||||
errmsg("unreachable WHEN clause specified after unconditional WHEN clause"))); |
||||
} |
||||
|
||||
/* Set up the MERGE target table. */ |
||||
qry->resultRelation = setTargetTable(pstate, stmt->relation, |
||||
stmt->relation->inh, |
||||
false, targetPerms); |
||||
|
||||
/*
|
||||
* MERGE is unsupported in various cases |
||||
*/ |
||||
if (pstate->p_target_relation->rd_rel->relkind != RELKIND_RELATION && |
||||
pstate->p_target_relation->rd_rel->relkind != RELKIND_PARTITIONED_TABLE) |
||||
ereport(ERROR, |
||||
(errcode(ERRCODE_FEATURE_NOT_SUPPORTED), |
||||
errmsg("cannot execute MERGE on relation \"%s\"", |
||||
RelationGetRelationName(pstate->p_target_relation)), |
||||
errdetail_relkind_not_supported(pstate->p_target_relation->rd_rel->relkind))); |
||||
if (pstate->p_target_relation->rd_rel->relhasrules) |
||||
ereport(ERROR, |
||||
(errcode(ERRCODE_FEATURE_NOT_SUPPORTED), |
||||
errmsg("cannot execute MERGE on relation \"%s\"", |
||||
RelationGetRelationName(pstate->p_target_relation)), |
||||
errdetail("MERGE is not supported for relations with rules."))); |
||||
|
||||
/* Now transform the source relation to produce the source RTE. */ |
||||
transformFromClause(pstate, |
||||
list_make1(stmt->sourceRelation)); |
||||
sourceRTI = list_length(pstate->p_rtable); |
||||
nsitem = GetNSItemByRangeTablePosn(pstate, sourceRTI, 0); |
||||
|
||||
/*
|
||||
* Check that the target table doesn't conflict with the source table. |
||||
* This would typically be a checkNameSpaceConflicts call, but we want a |
||||
* more specific error message. |
||||
*/ |
||||
if (strcmp(pstate->p_target_nsitem->p_names->aliasname, |
||||
nsitem->p_names->aliasname) == 0) |
||||
ereport(ERROR, |
||||
errcode(ERRCODE_DUPLICATE_ALIAS), |
||||
errmsg("name \"%s\" specified more than once", |
||||
pstate->p_target_nsitem->p_names->aliasname), |
||||
errdetail("The name is used both as MERGE target table and data source.")); |
||||
|
||||
qry->targetList = expandNSItemAttrs(pstate, nsitem, 0, false, |
||||
exprLocation(stmt->sourceRelation)); |
||||
|
||||
qry->rtable = pstate->p_rtable; |
||||
|
||||
/*
|
||||
* Transform the join condition. This includes references to the target |
||||
* side, so add that to the namespace. |
||||
*/ |
||||
addNSItemToQuery(pstate, pstate->p_target_nsitem, false, true, true); |
||||
joinExpr = transformExpr(pstate, stmt->joinCondition, |
||||
EXPR_KIND_JOIN_ON); |
||||
|
||||
/*
|
||||
* Create the temporary query's jointree using the joinlist we built using |
||||
* just the source relation; the target relation is not included. The |
||||
* quals we use are the join conditions to the merge target. The join |
||||
* will be constructed fully by transform_MERGE_to_join. |
||||
*/ |
||||
qry->jointree = makeFromExpr(pstate->p_joinlist, joinExpr); |
||||
|
||||
/*
|
||||
* We now have a good query shape, so now look at the WHEN conditions and |
||||
* action targetlists. |
||||
* |
||||
* Overall, the MERGE Query's targetlist is NIL. |
||||
* |
||||
* Each individual action has its own targetlist that needs separate |
||||
* transformation. These transforms don't do anything to the overall |
||||
* targetlist, since that is only used for resjunk columns. |
||||
* |
||||
* We can reference any column in Target or Source, which is OK because |
||||
* both of those already have RTEs. There is nothing like the EXCLUDED |
||||
* pseudo-relation for INSERT ON CONFLICT. |
||||
*/ |
||||
mergeActionList = NIL; |
||||
foreach(l, stmt->mergeWhenClauses) |
||||
{ |
||||
MergeWhenClause *mergeWhenClause = lfirst_node(MergeWhenClause, l); |
||||
MergeAction *action; |
||||
|
||||
action = makeNode(MergeAction); |
||||
action->commandType = mergeWhenClause->commandType; |
||||
action->matched = mergeWhenClause->matched; |
||||
|
||||
/* Use an outer join if any INSERT actions exist in the command. */ |
||||
if (action->commandType == CMD_INSERT) |
||||
qry->mergeUseOuterJoin = true; |
||||
|
||||
/*
|
||||
* Set namespace for the specific action. This must be done before |
||||
* analyzing the WHEN quals and the action targetlist. |
||||
*/ |
||||
setNamespaceForMergeWhen(pstate, mergeWhenClause, |
||||
qry->resultRelation, |
||||
sourceRTI); |
||||
|
||||
/*
|
||||
* Transform the WHEN condition. |
||||
* |
||||
* Note that these quals are NOT added to the join quals; instead they |
||||
* are evaluated separately during execution to decide which of the |
||||
* WHEN MATCHED or WHEN NOT MATCHED actions to execute. |
||||
*/ |
||||
action->qual = transformWhereClause(pstate, mergeWhenClause->condition, |
||||
EXPR_KIND_MERGE_WHEN, "WHEN"); |
||||
|
||||
/*
|
||||
* Transform target lists for each INSERT and UPDATE action stmt |
||||
*/ |
||||
switch (action->commandType) |
||||
{ |
||||
case CMD_INSERT: |
||||
{ |
||||
List *exprList = NIL; |
||||
ListCell *lc; |
||||
RangeTblEntry *rte; |
||||
ListCell *icols; |
||||
ListCell *attnos; |
||||
List *icolumns; |
||||
List *attrnos; |
||||
|
||||
pstate->p_is_insert = true; |
||||
|
||||
icolumns = checkInsertTargets(pstate, |
||||
mergeWhenClause->targetList, |
||||
&attrnos); |
||||
Assert(list_length(icolumns) == list_length(attrnos)); |
||||
|
||||
action->override = mergeWhenClause->override; |
||||
|
||||
/*
|
||||
* Handle INSERT much like in transformInsertStmt |
||||
*/ |
||||
if (mergeWhenClause->values == NIL) |
||||
{ |
||||
/*
|
||||
* We have INSERT ... DEFAULT VALUES. We can handle |
||||
* this case by emitting an empty targetlist --- all |
||||
* columns will be defaulted when the planner expands |
||||
* the targetlist. |
||||
*/ |
||||
exprList = NIL; |
||||
} |
||||
else |
||||
{ |
||||
/*
|
||||
* Process INSERT ... VALUES with a single VALUES |
||||
* sublist. We treat this case separately for |
||||
* efficiency. The sublist is just computed directly |
||||
* as the Query's targetlist, with no VALUES RTE. So |
||||
* it works just like a SELECT without any FROM. |
||||
*/ |
||||
|
||||
/*
|
||||
* Do basic expression transformation (same as a ROW() |
||||
* expr, but allow SetToDefault at top level) |
||||
*/ |
||||
exprList = transformExpressionList(pstate, |
||||
mergeWhenClause->values, |
||||
EXPR_KIND_VALUES_SINGLE, |
||||
true); |
||||
|
||||
/* Prepare row for assignment to target table */ |
||||
exprList = transformInsertRow(pstate, exprList, |
||||
mergeWhenClause->targetList, |
||||
icolumns, attrnos, |
||||
false); |
||||
} |
||||
|
||||
/*
|
||||
* Generate action's target list using the computed list |
||||
* of expressions. Also, mark all the target columns as |
||||
* needing insert permissions. |
||||
*/ |
||||
rte = pstate->p_target_nsitem->p_rte; |
||||
forthree(lc, exprList, icols, icolumns, attnos, attrnos) |
||||
{ |
||||
Expr *expr = (Expr *) lfirst(lc); |
||||
ResTarget *col = lfirst_node(ResTarget, icols); |
||||
AttrNumber attr_num = (AttrNumber) lfirst_int(attnos); |
||||
TargetEntry *tle; |
||||
|
||||
tle = makeTargetEntry(expr, |
||||
attr_num, |
||||
col->name, |
||||
false); |
||||
action->targetList = lappend(action->targetList, tle); |
||||
|
||||
rte->insertedCols = |
||||
bms_add_member(rte->insertedCols, |
||||
attr_num - FirstLowInvalidHeapAttributeNumber); |
||||
} |
||||
} |
||||
break; |
||||
case CMD_UPDATE: |
||||
{ |
||||
pstate->p_is_insert = false; |
||||
action->targetList = |
||||
transformUpdateTargetList(pstate, |
||||
mergeWhenClause->targetList); |
||||
} |
||||
break; |
||||
case CMD_DELETE: |
||||
break; |
||||
|
||||
case CMD_NOTHING: |
||||
action->targetList = NIL; |
||||
break; |
||||
default: |
||||
elog(ERROR, "unknown action in MERGE WHEN clause"); |
||||
} |
||||
|
||||
mergeActionList = lappend(mergeActionList, action); |
||||
} |
||||
|
||||
qry->mergeActionList = mergeActionList; |
||||
|
||||
/* RETURNING could potentially be added in the future, but not in SQL std */ |
||||
qry->returningList = NULL; |
||||
|
||||
qry->hasTargetSRFs = false; |
||||
qry->hasSubLinks = pstate->p_hasSubLinks; |
||||
|
||||
assign_query_collations(pstate, qry); |
||||
|
||||
return qry; |
||||
} |
||||
|
||||
static void |
||||
setNamespaceVisibilityForRTE(List *namespace, RangeTblEntry *rte, |
||||
bool rel_visible, |
||||
bool cols_visible) |
||||
{ |
||||
ListCell *lc; |
||||
|
||||
foreach(lc, namespace) |
||||
{ |
||||
ParseNamespaceItem *nsitem = (ParseNamespaceItem *) lfirst(lc); |
||||
|
||||
if (nsitem->p_rte == rte) |
||||
{ |
||||
nsitem->p_rel_visible = rel_visible; |
||||
nsitem->p_cols_visible = cols_visible; |
||||
break; |
||||
} |
||||
} |
||||
} |
@ -0,0 +1,21 @@ |
||||
/*-------------------------------------------------------------------------
|
||||
* |
||||
* parse_merge.h |
||||
* handle MERGE statement in parser |
||||
* |
||||
* |
||||
* Portions Copyright (c) 1996-2022, PostgreSQL Global Development Group |
||||
* Portions Copyright (c) 1994, Regents of the University of California |
||||
* |
||||
* src/include/parser/parse_merge.h |
||||
* |
||||
*------------------------------------------------------------------------- |
||||
*/ |
||||
#ifndef PARSE_MERGE_H |
||||
#define PARSE_MERGE_H |
||||
|
||||
#include "parser/parse_node.h" |
||||
|
||||
extern Query *transformMergeStmt(ParseState *pstate, MergeStmt *stmt); |
||||
|
||||
#endif /* PARSE_MERGE_H */ |
@ -0,0 +1,117 @@ |
||||
Parsed test spec with 2 sessions |
||||
|
||||
starting permutation: delete c1 select2 c2 |
||||
step delete: DELETE FROM target t WHERE t.key = 1; |
||||
step c1: COMMIT; |
||||
step select2: SELECT * FROM target; |
||||
key|val |
||||
---+--- |
||||
(0 rows) |
||||
|
||||
step c2: COMMIT; |
||||
|
||||
starting permutation: merge_delete c1 select2 c2 |
||||
step merge_delete: MERGE INTO target t USING (SELECT 1 as key) s ON s.key = t.key WHEN MATCHED THEN DELETE; |
||||
step c1: COMMIT; |
||||
step select2: SELECT * FROM target; |
||||
key|val |
||||
---+--- |
||||
(0 rows) |
||||
|
||||
step c2: COMMIT; |
||||
|
||||
starting permutation: delete c1 update1 select2 c2 |
||||
step delete: DELETE FROM target t WHERE t.key = 1; |
||||
step c1: COMMIT; |
||||
step update1: UPDATE target t SET val = t.val || ' updated by update1' WHERE t.key = 1; |
||||
step select2: SELECT * FROM target; |
||||
key|val |
||||
---+--- |
||||
(0 rows) |
||||
|
||||
step c2: COMMIT; |
||||
|
||||
starting permutation: merge_delete c1 update1 select2 c2 |
||||
step merge_delete: MERGE INTO target t USING (SELECT 1 as key) s ON s.key = t.key WHEN MATCHED THEN DELETE; |
||||
step c1: COMMIT; |
||||
step update1: UPDATE target t SET val = t.val || ' updated by update1' WHERE t.key = 1; |
||||
step select2: SELECT * FROM target; |
||||
key|val |
||||
---+--- |
||||
(0 rows) |
||||
|
||||
step c2: COMMIT; |
||||
|
||||
starting permutation: delete c1 merge2 select2 c2 |
||||
step delete: DELETE FROM target t WHERE t.key = 1; |
||||
step c1: COMMIT; |
||||
step merge2: MERGE INTO target t USING (SELECT 1 as key, 'merge2a' as val) s ON s.key = t.key WHEN NOT MATCHED THEN INSERT VALUES (s.key, s.val) WHEN MATCHED THEN UPDATE set key = t.key + 1, val = t.val || ' updated by ' || s.val; |
||||
step select2: SELECT * FROM target; |
||||
key|val |
||||
---+------- |
||||
1|merge2a |
||||
(1 row) |
||||
|
||||
step c2: COMMIT; |
||||
|
||||
starting permutation: merge_delete c1 merge2 select2 c2 |
||||
step merge_delete: MERGE INTO target t USING (SELECT 1 as key) s ON s.key = t.key WHEN MATCHED THEN DELETE; |
||||
step c1: COMMIT; |
||||
step merge2: MERGE INTO target t USING (SELECT 1 as key, 'merge2a' as val) s ON s.key = t.key WHEN NOT MATCHED THEN INSERT VALUES (s.key, s.val) WHEN MATCHED THEN UPDATE set key = t.key + 1, val = t.val || ' updated by ' || s.val; |
||||
step select2: SELECT * FROM target; |
||||
key|val |
||||
---+------- |
||||
1|merge2a |
||||
(1 row) |
||||
|
||||
step c2: COMMIT; |
||||
|
||||
starting permutation: delete update1 c1 select2 c2 |
||||
step delete: DELETE FROM target t WHERE t.key = 1; |
||||
step update1: UPDATE target t SET val = t.val || ' updated by update1' WHERE t.key = 1; <waiting ...> |
||||
step c1: COMMIT; |
||||
step update1: <... completed> |
||||
step select2: SELECT * FROM target; |
||||
key|val |
||||
---+--- |
||||
(0 rows) |
||||
|
||||
step c2: COMMIT; |
||||
|
||||
starting permutation: merge_delete update1 c1 select2 c2 |
||||
step merge_delete: MERGE INTO target t USING (SELECT 1 as key) s ON s.key = t.key WHEN MATCHED THEN DELETE; |
||||
step update1: UPDATE target t SET val = t.val || ' updated by update1' WHERE t.key = 1; <waiting ...> |
||||
step c1: COMMIT; |
||||
step update1: <... completed> |
||||
step select2: SELECT * FROM target; |
||||
key|val |
||||
---+--- |
||||
(0 rows) |
||||
|
||||
step c2: COMMIT; |
||||
|
||||
starting permutation: delete merge2 c1 select2 c2 |
||||
step delete: DELETE FROM target t WHERE t.key = 1; |
||||
step merge2: MERGE INTO target t USING (SELECT 1 as key, 'merge2a' as val) s ON s.key = t.key WHEN NOT MATCHED THEN INSERT VALUES (s.key, s.val) WHEN MATCHED THEN UPDATE set key = t.key + 1, val = t.val || ' updated by ' || s.val; <waiting ...> |
||||
step c1: COMMIT; |
||||
step merge2: <... completed> |
||||
step select2: SELECT * FROM target; |
||||
key|val |
||||
---+------- |
||||
1|merge2a |
||||
(1 row) |
||||
|
||||
step c2: COMMIT; |
||||
|
||||
starting permutation: merge_delete merge2 c1 select2 c2 |
||||
step merge_delete: MERGE INTO target t USING (SELECT 1 as key) s ON s.key = t.key WHEN MATCHED THEN DELETE; |
||||
step merge2: MERGE INTO target t USING (SELECT 1 as key, 'merge2a' as val) s ON s.key = t.key WHEN NOT MATCHED THEN INSERT VALUES (s.key, s.val) WHEN MATCHED THEN UPDATE set key = t.key + 1, val = t.val || ' updated by ' || s.val; <waiting ...> |
||||
step c1: COMMIT; |
||||
step merge2: <... completed> |
||||
step select2: SELECT * FROM target; |
||||
key|val |
||||
---+------- |
||||
1|merge2a |
||||
(1 row) |
||||
|
||||
step c2: COMMIT; |
@ -0,0 +1,94 @@ |
||||
Parsed test spec with 2 sessions |
||||
|
||||
starting permutation: merge1 c1 select2 c2 |
||||
step merge1: MERGE INTO target t USING (SELECT 1 as key, 'merge1' as val) s ON s.key = t.key WHEN NOT MATCHED THEN INSERT VALUES (s.key, s.val) WHEN MATCHED THEN UPDATE set val = t.val || ' updated by merge1'; |
||||
step c1: COMMIT; |
||||
step select2: SELECT * FROM target; |
||||
key|val |
||||
---+------ |
||||
1|merge1 |
||||
(1 row) |
||||
|
||||
step c2: COMMIT; |
||||
|
||||
starting permutation: merge1 c1 merge2 select2 c2 |
||||
step merge1: MERGE INTO target t USING (SELECT 1 as key, 'merge1' as val) s ON s.key = t.key WHEN NOT MATCHED THEN INSERT VALUES (s.key, s.val) WHEN MATCHED THEN UPDATE set val = t.val || ' updated by merge1'; |
||||
step c1: COMMIT; |
||||
step merge2: MERGE INTO target t USING (SELECT 1 as key, 'merge2' as val) s ON s.key = t.key WHEN NOT MATCHED THEN INSERT VALUES (s.key, s.val) WHEN MATCHED THEN UPDATE set val = t.val || ' updated by merge2'; |
||||
step select2: SELECT * FROM target; |
||||
key|val |
||||
---+------------------------ |
||||
1|merge1 updated by merge2 |
||||
(1 row) |
||||
|
||||
step c2: COMMIT; |
||||
|
||||
starting permutation: insert1 merge2 c1 select2 c2 |
||||
step insert1: INSERT INTO target VALUES (1, 'insert1'); |
||||
step merge2: MERGE INTO target t USING (SELECT 1 as key, 'merge2' as val) s ON s.key = t.key WHEN NOT MATCHED THEN INSERT VALUES (s.key, s.val) WHEN MATCHED THEN UPDATE set val = t.val || ' updated by merge2'; <waiting ...> |
||||
step c1: COMMIT; |
||||
step merge2: <... completed> |
||||
ERROR: duplicate key value violates unique constraint "target_pkey" |
||||
step select2: SELECT * FROM target; |
||||
ERROR: current transaction is aborted, commands ignored until end of transaction block |
||||
step c2: COMMIT; |
||||
|
||||
starting permutation: merge1 merge2 c1 select2 c2 |
||||
step merge1: MERGE INTO target t USING (SELECT 1 as key, 'merge1' as val) s ON s.key = t.key WHEN NOT MATCHED THEN INSERT VALUES (s.key, s.val) WHEN MATCHED THEN UPDATE set val = t.val || ' updated by merge1'; |
||||
step merge2: MERGE INTO target t USING (SELECT 1 as key, 'merge2' as val) s ON s.key = t.key WHEN NOT MATCHED THEN INSERT VALUES (s.key, s.val) WHEN MATCHED THEN UPDATE set val = t.val || ' updated by merge2'; <waiting ...> |
||||
step c1: COMMIT; |
||||
step merge2: <... completed> |
||||
ERROR: duplicate key value violates unique constraint "target_pkey" |
||||
step select2: SELECT * FROM target; |
||||
ERROR: current transaction is aborted, commands ignored until end of transaction block |
||||
step c2: COMMIT; |
||||
|
||||
starting permutation: merge1 merge2 a1 select2 c2 |
||||
step merge1: MERGE INTO target t USING (SELECT 1 as key, 'merge1' as val) s ON s.key = t.key WHEN NOT MATCHED THEN INSERT VALUES (s.key, s.val) WHEN MATCHED THEN UPDATE set val = t.val || ' updated by merge1'; |
||||
step merge2: MERGE INTO target t USING (SELECT 1 as key, 'merge2' as val) s ON s.key = t.key WHEN NOT MATCHED THEN INSERT VALUES (s.key, s.val) WHEN MATCHED THEN UPDATE set val = t.val || ' updated by merge2'; <waiting ...> |
||||
step a1: ABORT; |
||||
step merge2: <... completed> |
||||
step select2: SELECT * FROM target; |
||||
key|val |
||||
---+------ |
||||
1|merge2 |
||||
(1 row) |
||||
|
||||
step c2: COMMIT; |
||||
|
||||
starting permutation: delete1 insert1 c1 merge2 select2 c2 |
||||
step delete1: DELETE FROM target WHERE key = 1; |
||||
step insert1: INSERT INTO target VALUES (1, 'insert1'); |
||||
step c1: COMMIT; |
||||
step merge2: MERGE INTO target t USING (SELECT 1 as key, 'merge2' as val) s ON s.key = t.key WHEN NOT MATCHED THEN INSERT VALUES (s.key, s.val) WHEN MATCHED THEN UPDATE set val = t.val || ' updated by merge2'; |
||||
step select2: SELECT * FROM target; |
||||
key|val |
||||
---+------------------------- |
||||
1|insert1 updated by merge2 |
||||
(1 row) |
||||
|
||||
step c2: COMMIT; |
||||
|
||||
starting permutation: delete1 insert1 merge2 c1 select2 c2 |
||||
step delete1: DELETE FROM target WHERE key = 1; |
||||
step insert1: INSERT INTO target VALUES (1, 'insert1'); |
||||
step merge2: MERGE INTO target t USING (SELECT 1 as key, 'merge2' as val) s ON s.key = t.key WHEN NOT MATCHED THEN INSERT VALUES (s.key, s.val) WHEN MATCHED THEN UPDATE set val = t.val || ' updated by merge2'; <waiting ...> |
||||
step c1: COMMIT; |
||||
step merge2: <... completed> |
||||
ERROR: duplicate key value violates unique constraint "target_pkey" |
||||
step select2: SELECT * FROM target; |
||||
ERROR: current transaction is aborted, commands ignored until end of transaction block |
||||
step c2: COMMIT; |
||||
|
||||
starting permutation: delete1 insert1 merge2i c1 select2 c2 |
||||
step delete1: DELETE FROM target WHERE key = 1; |
||||
step insert1: INSERT INTO target VALUES (1, 'insert1'); |
||||
step merge2i: MERGE INTO target t USING (SELECT 1 as key, 'merge2' as val) s ON s.key = t.key WHEN MATCHED THEN UPDATE set val = t.val || ' updated by merge2'; |
||||
step c1: COMMIT; |
||||
step select2: SELECT * FROM target; |
||||
key|val |
||||
---+------- |
||||
1|insert1 |
||||
(1 row) |
||||
|
||||
step c2: COMMIT; |
@ -0,0 +1,116 @@ |
||||
Parsed test spec with 2 sessions |
||||
|
||||
starting permutation: update1 merge_status c2 select1 c1 |
||||
step update1: UPDATE target t SET balance = balance + 10, val = t.val || ' updated by update1' WHERE t.key = 1; |
||||
step merge_status: |
||||
MERGE INTO target t |
||||
USING (SELECT 1 as key) s |
||||
ON s.key = t.key |
||||
WHEN MATCHED AND status = 's1' THEN |
||||
UPDATE SET status = 's2', val = t.val || ' when1' |
||||
WHEN MATCHED AND status = 's2' THEN |
||||
UPDATE SET status = 's3', val = t.val || ' when2' |
||||
WHEN MATCHED AND status = 's3' THEN |
||||
UPDATE SET status = 's4', val = t.val || ' when3'; |
||||
<waiting ...> |
||||
step c2: COMMIT; |
||||
step merge_status: <... completed> |
||||
step select1: SELECT * FROM target; |
||||
key|balance|status|val |
||||
---+-------+------+------------------------------ |
||||
1| 170|s2 |setup updated by update1 when1 |
||||
(1 row) |
||||
|
||||
step c1: COMMIT; |
||||
|
||||
starting permutation: update2 merge_status c2 select1 c1 |
||||
step update2: UPDATE target t SET status = 's2', val = t.val || ' updated by update2' WHERE t.key = 1; |
||||
step merge_status: |
||||
MERGE INTO target t |
||||
USING (SELECT 1 as key) s |
||||
ON s.key = t.key |
||||
WHEN MATCHED AND status = 's1' THEN |
||||
UPDATE SET status = 's2', val = t.val || ' when1' |
||||
WHEN MATCHED AND status = 's2' THEN |
||||
UPDATE SET status = 's3', val = t.val || ' when2' |
||||
WHEN MATCHED AND status = 's3' THEN |
||||
UPDATE SET status = 's4', val = t.val || ' when3'; |
||||
<waiting ...> |
||||
step c2: COMMIT; |
||||
step merge_status: <... completed> |
||||
step select1: SELECT * FROM target; |
||||
key|balance|status|val |
||||
---+-------+------+------------------------------ |
||||
1| 160|s3 |setup updated by update2 when2 |
||||
(1 row) |
||||
|
||||
step c1: COMMIT; |
||||
|
||||
starting permutation: update3 merge_status c2 select1 c1 |
||||
step update3: UPDATE target t SET status = 's3', val = t.val || ' updated by update3' WHERE t.key = 1; |
||||
step merge_status: |
||||
MERGE INTO target t |
||||
USING (SELECT 1 as key) s |
||||
ON s.key = t.key |
||||
WHEN MATCHED AND status = 's1' THEN |
||||
UPDATE SET status = 's2', val = t.val || ' when1' |
||||
WHEN MATCHED AND status = 's2' THEN |
||||
UPDATE SET status = 's3', val = t.val || ' when2' |
||||
WHEN MATCHED AND status = 's3' THEN |
||||
UPDATE SET status = 's4', val = t.val || ' when3'; |
||||
<waiting ...> |
||||
step c2: COMMIT; |
||||
step merge_status: <... completed> |
||||
step select1: SELECT * FROM target; |
||||
key|balance|status|val |
||||
---+-------+------+------------------------------ |
||||
1| 160|s4 |setup updated by update3 when3 |
||||
(1 row) |
||||
|
||||
step c1: COMMIT; |
||||
|
||||
starting permutation: update5 merge_status c2 select1 c1 |
||||
step update5: UPDATE target t SET status = 's5', val = t.val || ' updated by update5' WHERE t.key = 1; |
||||
step merge_status: |
||||
MERGE INTO target t |
||||
USING (SELECT 1 as key) s |
||||
ON s.key = t.key |
||||
WHEN MATCHED AND status = 's1' THEN |
||||
UPDATE SET status = 's2', val = t.val || ' when1' |
||||
WHEN MATCHED AND status = 's2' THEN |
||||
UPDATE SET status = 's3', val = t.val || ' when2' |
||||
WHEN MATCHED AND status = 's3' THEN |
||||
UPDATE SET status = 's4', val = t.val || ' when3'; |
||||
<waiting ...> |
||||
step c2: COMMIT; |
||||
step merge_status: <... completed> |
||||
step select1: SELECT * FROM target; |
||||
key|balance|status|val |
||||
---+-------+------+------------------------ |
||||
1| 160|s5 |setup updated by update5 |
||||
(1 row) |
||||
|
||||
step c1: COMMIT; |
||||
|
||||
starting permutation: update_bal1 merge_bal c2 select1 c1 |
||||
step update_bal1: UPDATE target t SET balance = 50, val = t.val || ' updated by update_bal1' WHERE t.key = 1; |
||||
step merge_bal: |
||||
MERGE INTO target t |
||||
USING (SELECT 1 as key) s |
||||
ON s.key = t.key |
||||
WHEN MATCHED AND balance < 100 THEN |
||||
UPDATE SET balance = balance * 2, val = t.val || ' when1' |
||||
WHEN MATCHED AND balance < 200 THEN |
||||
UPDATE SET balance = balance * 4, val = t.val || ' when2' |
||||
WHEN MATCHED AND balance < 300 THEN |
||||
UPDATE SET balance = balance * 8, val = t.val || ' when3'; |
||||
<waiting ...> |
||||
step c2: COMMIT; |
||||
step merge_bal: <... completed> |
||||
step select1: SELECT * FROM target; |
||||
key|balance|status|val |
||||
---+-------+------+---------------------------------- |
||||
1| 100|s1 |setup updated by update_bal1 when1 |
||||
(1 row) |
||||
|
||||
step c1: COMMIT; |
@ -0,0 +1,314 @@ |
||||
Parsed test spec with 2 sessions |
||||
|
||||
starting permutation: merge1 c1 select2 c2 |
||||
step merge1: |
||||
MERGE INTO target t |
||||
USING (SELECT 1 as key, 'merge1' as val) s |
||||
ON s.key = t.key |
||||
WHEN NOT MATCHED THEN |
||||
INSERT VALUES (s.key, s.val) |
||||
WHEN MATCHED THEN |
||||
UPDATE set key = t.key + 1, val = t.val || ' updated by ' || s.val; |
||||
|
||||
step c1: COMMIT; |
||||
step select2: SELECT * FROM target; |
||||
key|val |
||||
---+------------------------ |
||||
2|setup1 updated by merge1 |
||||
(1 row) |
||||
|
||||
step c2: COMMIT; |
||||
|
||||
starting permutation: merge1 c1 merge2a select2 c2 |
||||
step merge1: |
||||
MERGE INTO target t |
||||
USING (SELECT 1 as key, 'merge1' as val) s |
||||
ON s.key = t.key |
||||
WHEN NOT MATCHED THEN |
||||
INSERT VALUES (s.key, s.val) |
||||
WHEN MATCHED THEN |
||||
UPDATE set key = t.key + 1, val = t.val || ' updated by ' || s.val; |
||||
|
||||
step c1: COMMIT; |
||||
step merge2a: |
||||
MERGE INTO target t |
||||
USING (SELECT 1 as key, 'merge2a' as val) s |
||||
ON s.key = t.key |
||||
WHEN NOT MATCHED THEN |
||||
INSERT VALUES (s.key, s.val) |
||||
WHEN MATCHED THEN |
||||
UPDATE set key = t.key + 1, val = t.val || ' updated by ' || s.val; |
||||
|
||||
step select2: SELECT * FROM target; |
||||
key|val |
||||
---+------------------------ |
||||
2|setup1 updated by merge1 |
||||
1|merge2a |
||||
(2 rows) |
||||
|
||||
step c2: COMMIT; |
||||
|
||||
starting permutation: merge1 merge2a c1 select2 c2 |
||||
step merge1: |
||||
MERGE INTO target t |
||||
USING (SELECT 1 as key, 'merge1' as val) s |
||||
ON s.key = t.key |
||||
WHEN NOT MATCHED THEN |
||||
INSERT VALUES (s.key, s.val) |
||||
WHEN MATCHED THEN |
||||
UPDATE set key = t.key + 1, val = t.val || ' updated by ' || s.val; |
||||
|
||||
step merge2a: |
||||
MERGE INTO target t |
||||
USING (SELECT 1 as key, 'merge2a' as val) s |
||||
ON s.key = t.key |
||||
WHEN NOT MATCHED THEN |
||||
INSERT VALUES (s.key, s.val) |
||||
WHEN MATCHED THEN |
||||
UPDATE set key = t.key + 1, val = t.val || ' updated by ' || s.val; |
||||
<waiting ...> |
||||
step c1: COMMIT; |
||||
step merge2a: <... completed> |
||||
step select2: SELECT * FROM target; |
||||
key|val |
||||
---+------------------------ |
||||
2|setup1 updated by merge1 |
||||
1|merge2a |
||||
(2 rows) |
||||
|
||||
step c2: COMMIT; |
||||
|
||||
starting permutation: merge1 merge2a a1 select2 c2 |
||||
step merge1: |
||||
MERGE INTO target t |
||||
USING (SELECT 1 as key, 'merge1' as val) s |
||||
ON s.key = t.key |
||||
WHEN NOT MATCHED THEN |
||||
INSERT VALUES (s.key, s.val) |
||||
WHEN MATCHED THEN |
||||
UPDATE set key = t.key + 1, val = t.val || ' updated by ' || s.val; |
||||
|
||||
step merge2a: |
||||
MERGE INTO target t |
||||
USING (SELECT 1 as key, 'merge2a' as val) s |
||||
ON s.key = t.key |
||||
WHEN NOT MATCHED THEN |
||||
INSERT VALUES (s.key, s.val) |
||||
WHEN MATCHED THEN |
||||
UPDATE set key = t.key + 1, val = t.val || ' updated by ' || s.val; |
||||
<waiting ...> |
||||
step a1: ABORT; |
||||
step merge2a: <... completed> |
||||
step select2: SELECT * FROM target; |
||||
key|val |
||||
---+------------------------- |
||||
2|setup1 updated by merge2a |
||||
(1 row) |
||||
|
||||
step c2: COMMIT; |
||||
|
||||
starting permutation: merge1 merge2b c1 select2 c2 |
||||
step merge1: |
||||
MERGE INTO target t |
||||
USING (SELECT 1 as key, 'merge1' as val) s |
||||
ON s.key = t.key |
||||
WHEN NOT MATCHED THEN |
||||
INSERT VALUES (s.key, s.val) |
||||
WHEN MATCHED THEN |
||||
UPDATE set key = t.key + 1, val = t.val || ' updated by ' || s.val; |
||||
|
||||
step merge2b: |
||||
MERGE INTO target t |
||||
USING (SELECT 1 as key, 'merge2b' as val) s |
||||
ON s.key = t.key |
||||
WHEN NOT MATCHED THEN |
||||
INSERT VALUES (s.key, s.val) |
||||
WHEN MATCHED AND t.key < 2 THEN |
||||
UPDATE set key = t.key + 1, val = t.val || ' updated by ' || s.val; |
||||
<waiting ...> |
||||
step c1: COMMIT; |
||||
step merge2b: <... completed> |
||||
step select2: SELECT * FROM target; |
||||
key|val |
||||
---+------------------------ |
||||
2|setup1 updated by merge1 |
||||
1|merge2b |
||||
(2 rows) |
||||
|
||||
step c2: COMMIT; |
||||
|
||||
starting permutation: merge1 merge2c c1 select2 c2 |
||||
step merge1: |
||||
MERGE INTO target t |
||||
USING (SELECT 1 as key, 'merge1' as val) s |
||||
ON s.key = t.key |
||||
WHEN NOT MATCHED THEN |
||||
INSERT VALUES (s.key, s.val) |
||||
WHEN MATCHED THEN |
||||
UPDATE set key = t.key + 1, val = t.val || ' updated by ' || s.val; |
||||
|
||||
step merge2c: |
||||
MERGE INTO target t |
||||
USING (SELECT 1 as key, 'merge2c' as val) s |
||||
ON s.key = t.key AND t.key < 2 |
||||
WHEN NOT MATCHED THEN |
||||
INSERT VALUES (s.key, s.val) |
||||
WHEN MATCHED THEN |
||||
UPDATE set key = t.key + 1, val = t.val || ' updated by ' || s.val; |
||||
<waiting ...> |
||||
step c1: COMMIT; |
||||
step merge2c: <... completed> |
||||
step select2: SELECT * FROM target; |
||||
key|val |
||||
---+------------------------ |
||||
2|setup1 updated by merge1 |
||||
1|merge2c |
||||
(2 rows) |
||||
|
||||
step c2: COMMIT; |
||||
|
||||
starting permutation: pa_merge1 pa_merge2a c1 pa_select2 c2 |
||||
step pa_merge1: |
||||
MERGE INTO pa_target t |
||||
USING (SELECT 1 as key, 'pa_merge1' as val) s |
||||
ON s.key = t.key |
||||
WHEN NOT MATCHED THEN |
||||
INSERT VALUES (s.key, s.val) |
||||
WHEN MATCHED THEN |
||||
UPDATE set val = t.val || ' updated by ' || s.val; |
||||
|
||||
step pa_merge2a: |
||||
MERGE INTO pa_target t |
||||
USING (SELECT 1 as key, 'pa_merge2a' as val) s |
||||
ON s.key = t.key |
||||
WHEN NOT MATCHED THEN |
||||
INSERT VALUES (s.key, s.val) |
||||
WHEN MATCHED THEN |
||||
UPDATE set key = t.key + 1, val = t.val || ' updated by ' || s.val; |
||||
<waiting ...> |
||||
step c1: COMMIT; |
||||
step pa_merge2a: <... completed> |
||||
step pa_select2: SELECT * FROM pa_target; |
||||
key|val |
||||
---+-------------------------------------------------- |
||||
2|initial |
||||
2|initial updated by pa_merge1 updated by pa_merge2a |
||||
(2 rows) |
||||
|
||||
step c2: COMMIT; |
||||
|
||||
starting permutation: pa_merge2 pa_merge2a c1 pa_select2 c2 |
||||
step pa_merge2: |
||||
MERGE INTO pa_target t |
||||
USING (SELECT 1 as key, 'pa_merge2' as val) s |
||||
ON s.key = t.key |
||||
WHEN NOT MATCHED THEN |
||||
INSERT VALUES (s.key, s.val) |
||||
WHEN MATCHED THEN |
||||
UPDATE set key = t.key + 1, val = t.val || ' updated by ' || s.val; |
||||
|
||||
step pa_merge2a: |
||||
MERGE INTO pa_target t |
||||
USING (SELECT 1 as key, 'pa_merge2a' as val) s |
||||
ON s.key = t.key |
||||
WHEN NOT MATCHED THEN |
||||
INSERT VALUES (s.key, s.val) |
||||
WHEN MATCHED THEN |
||||
UPDATE set key = t.key + 1, val = t.val || ' updated by ' || s.val; |
||||
<waiting ...> |
||||
step c1: COMMIT; |
||||
step pa_merge2a: <... completed> |
||||
ERROR: tuple to be locked was already moved to another partition due to concurrent update |
||||
step pa_select2: SELECT * FROM pa_target; |
||||
ERROR: current transaction is aborted, commands ignored until end of transaction block |
||||
step c2: COMMIT; |
||||
|
||||
starting permutation: pa_merge2 c1 pa_merge2a pa_select2 c2 |
||||
step pa_merge2: |
||||
MERGE INTO pa_target t |
||||
USING (SELECT 1 as key, 'pa_merge2' as val) s |
||||
ON s.key = t.key |
||||
WHEN NOT MATCHED THEN |
||||
INSERT VALUES (s.key, s.val) |
||||
WHEN MATCHED THEN |
||||
UPDATE set key = t.key + 1, val = t.val || ' updated by ' || s.val; |
||||
|
||||
step c1: COMMIT; |
||||
step pa_merge2a: |
||||
MERGE INTO pa_target t |
||||
USING (SELECT 1 as key, 'pa_merge2a' as val) s |
||||
ON s.key = t.key |
||||
WHEN NOT MATCHED THEN |
||||
INSERT VALUES (s.key, s.val) |
||||
WHEN MATCHED THEN |
||||
UPDATE set key = t.key + 1, val = t.val || ' updated by ' || s.val; |
||||
|
||||
step pa_select2: SELECT * FROM pa_target; |
||||
key|val |
||||
---+---------------------------- |
||||
1|pa_merge2a |
||||
2|initial |
||||
2|initial updated by pa_merge2 |
||||
(3 rows) |
||||
|
||||
step c2: COMMIT; |
||||
|
||||
starting permutation: pa_merge3 pa_merge2b_when c1 pa_select2 c2 |
||||
step pa_merge3: |
||||
MERGE INTO pa_target t |
||||
USING (SELECT 1 as key, 'pa_merge2' as val) s |
||||
ON s.key = t.key |
||||
WHEN NOT MATCHED THEN |
||||
INSERT VALUES (s.key, s.val) |
||||
WHEN MATCHED THEN |
||||
UPDATE set val = 'prefix ' || t.val; |
||||
|
||||
step pa_merge2b_when: |
||||
MERGE INTO pa_target t |
||||
USING (SELECT 1 as key, 'pa_merge2b_when' as val) s |
||||
ON s.key = t.key |
||||
WHEN NOT MATCHED THEN |
||||
INSERT VALUES (s.key, s.val) |
||||
WHEN MATCHED AND t.val like 'initial%' THEN |
||||
UPDATE set key = t.key + 1, val = t.val || ' updated by ' || s.val; |
||||
<waiting ...> |
||||
step c1: COMMIT; |
||||
step pa_merge2b_when: <... completed> |
||||
step pa_select2: SELECT * FROM pa_target; |
||||
key|val |
||||
---+-------------- |
||||
1|prefix initial |
||||
2|initial |
||||
(2 rows) |
||||
|
||||
step c2: COMMIT; |
||||
|
||||
starting permutation: pa_merge1 pa_merge2b_when c1 pa_select2 c2 |
||||
step pa_merge1: |
||||
MERGE INTO pa_target t |
||||
USING (SELECT 1 as key, 'pa_merge1' as val) s |
||||
ON s.key = t.key |
||||
WHEN NOT MATCHED THEN |
||||
INSERT VALUES (s.key, s.val) |
||||
WHEN MATCHED THEN |
||||
UPDATE set val = t.val || ' updated by ' || s.val; |
||||
|
||||
step pa_merge2b_when: |
||||
MERGE INTO pa_target t |
||||
USING (SELECT 1 as key, 'pa_merge2b_when' as val) s |
||||
ON s.key = t.key |
||||
WHEN NOT MATCHED THEN |
||||
INSERT VALUES (s.key, s.val) |
||||
WHEN MATCHED AND t.val like 'initial%' THEN |
||||
UPDATE set key = t.key + 1, val = t.val || ' updated by ' || s.val; |
||||
<waiting ...> |
||||
step c1: COMMIT; |
||||
step pa_merge2b_when: <... completed> |
||||
step pa_select2: SELECT * FROM pa_target; |
||||
key|val |
||||
---+------------------------------------------------------- |
||||
2|initial |
||||
2|initial updated by pa_merge1 updated by pa_merge2b_when |
||||
(2 rows) |
||||
|
||||
step c2: COMMIT; |
@ -0,0 +1,50 @@ |
||||
# MERGE DELETE |
||||
# |
||||
# This test looks at the interactions involving concurrent deletes |
||||
# comparing the behavior of MERGE, DELETE and UPDATE |
||||
|
||||
setup |
||||
{ |
||||
CREATE TABLE target (key int primary key, val text); |
||||
INSERT INTO target VALUES (1, 'setup1'); |
||||
} |
||||
|
||||
teardown |
||||
{ |
||||
DROP TABLE target; |
||||
} |
||||
|
||||
session "s1" |
||||
setup |
||||
{ |
||||
BEGIN ISOLATION LEVEL READ COMMITTED; |
||||
} |
||||
step "delete" { DELETE FROM target t WHERE t.key = 1; } |
||||
step "merge_delete" { MERGE INTO target t USING (SELECT 1 as key) s ON s.key = t.key WHEN MATCHED THEN DELETE; } |
||||
step "c1" { COMMIT; } |
||||
|
||||
session "s2" |
||||
setup |
||||
{ |
||||
BEGIN ISOLATION LEVEL READ COMMITTED; |
||||
} |
||||
step "update1" { UPDATE target t SET val = t.val || ' updated by update1' WHERE t.key = 1; } |
||||
step "merge2" { MERGE INTO target t USING (SELECT 1 as key, 'merge2a' as val) s ON s.key = t.key WHEN NOT MATCHED THEN INSERT VALUES (s.key, s.val) WHEN MATCHED THEN UPDATE set key = t.key + 1, val = t.val || ' updated by ' || s.val; } |
||||
step "select2" { SELECT * FROM target; } |
||||
step "c2" { COMMIT; } |
||||
|
||||
# Basic effects |
||||
permutation "delete" "c1" "select2" "c2" |
||||
permutation "merge_delete" "c1" "select2" "c2" |
||||
|
||||
# One after the other, no concurrency |
||||
permutation "delete" "c1" "update1" "select2" "c2" |
||||
permutation "merge_delete" "c1" "update1" "select2" "c2" |
||||
permutation "delete" "c1" "merge2" "select2" "c2" |
||||
permutation "merge_delete" "c1" "merge2" "select2" "c2" |
||||
|
||||
# Now with concurrency |
||||
permutation "delete" "update1" "c1" "select2" "c2" |
||||
permutation "merge_delete" "update1" "c1" "select2" "c2" |
||||
permutation "delete" "merge2" "c1" "select2" "c2" |
||||
permutation "merge_delete" "merge2" "c1" "select2" "c2" |
@ -0,0 +1,51 @@ |
||||
# MERGE INSERT UPDATE |
||||
# |
||||
# This looks at how we handle concurrent INSERTs, illustrating how the |
||||
# behavior differs from INSERT ... ON CONFLICT |
||||
|
||||
setup |
||||
{ |
||||
CREATE TABLE target (key int primary key, val text); |
||||
} |
||||
|
||||
teardown |
||||
{ |
||||
DROP TABLE target; |
||||
} |
||||
|
||||
session "s1" |
||||
setup |
||||
{ |
||||
BEGIN ISOLATION LEVEL READ COMMITTED; |
||||
} |
||||
step "merge1" { MERGE INTO target t USING (SELECT 1 as key, 'merge1' as val) s ON s.key = t.key WHEN NOT MATCHED THEN INSERT VALUES (s.key, s.val) WHEN MATCHED THEN UPDATE set val = t.val || ' updated by merge1'; } |
||||
step "delete1" { DELETE FROM target WHERE key = 1; } |
||||
step "insert1" { INSERT INTO target VALUES (1, 'insert1'); } |
||||
step "c1" { COMMIT; } |
||||
step "a1" { ABORT; } |
||||
|
||||
session "s2" |
||||
setup |
||||
{ |
||||
BEGIN ISOLATION LEVEL READ COMMITTED; |
||||
} |
||||
step "merge2" { MERGE INTO target t USING (SELECT 1 as key, 'merge2' as val) s ON s.key = t.key WHEN NOT MATCHED THEN INSERT VALUES (s.key, s.val) WHEN MATCHED THEN UPDATE set val = t.val || ' updated by merge2'; } |
||||
|
||||
step "merge2i" { MERGE INTO target t USING (SELECT 1 as key, 'merge2' as val) s ON s.key = t.key WHEN MATCHED THEN UPDATE set val = t.val || ' updated by merge2'; } |
||||
|
||||
step "select2" { SELECT * FROM target; } |
||||
step "c2" { COMMIT; } |
||||
|
||||
# Basic effects |
||||
permutation "merge1" "c1" "select2" "c2" |
||||
permutation "merge1" "c1" "merge2" "select2" "c2" |
||||
|
||||
# check concurrent inserts |
||||
permutation "insert1" "merge2" "c1" "select2" "c2" |
||||
permutation "merge1" "merge2" "c1" "select2" "c2" |
||||
permutation "merge1" "merge2" "a1" "select2" "c2" |
||||
|
||||
# check how we handle when visible row has been concurrently deleted, then same key re-inserted |
||||
permutation "delete1" "insert1" "c1" "merge2" "select2" "c2" |
||||
permutation "delete1" "insert1" "merge2" "c1" "select2" "c2" |
||||
permutation "delete1" "insert1" "merge2i" "c1" "select2" "c2" |
@ -0,0 +1,77 @@ |
||||
# MERGE MATCHED RECHECK |
||||
# |
||||
# This test looks at what happens when we have complex |
||||
# WHEN MATCHED AND conditions and a concurrent UPDATE causes a |
||||
# recheck of the AND condition on the new row |
||||
|
||||
setup |
||||
{ |
||||
CREATE TABLE target (key int primary key, balance integer, status text, val text); |
||||
INSERT INTO target VALUES (1, 160, 's1', 'setup'); |
||||
} |
||||
|
||||
teardown |
||||
{ |
||||
DROP TABLE target; |
||||
} |
||||
|
||||
session "s1" |
||||
setup |
||||
{ |
||||
BEGIN ISOLATION LEVEL READ COMMITTED; |
||||
} |
||||
step "merge_status" |
||||
{ |
||||
MERGE INTO target t |
||||
USING (SELECT 1 as key) s |
||||
ON s.key = t.key |
||||
WHEN MATCHED AND status = 's1' THEN |
||||
UPDATE SET status = 's2', val = t.val || ' when1' |
||||
WHEN MATCHED AND status = 's2' THEN |
||||
UPDATE SET status = 's3', val = t.val || ' when2' |
||||
WHEN MATCHED AND status = 's3' THEN |
||||
UPDATE SET status = 's4', val = t.val || ' when3'; |
||||
} |
||||
|
||||
step "merge_bal" |
||||
{ |
||||
MERGE INTO target t |
||||
USING (SELECT 1 as key) s |
||||
ON s.key = t.key |
||||
WHEN MATCHED AND balance < 100 THEN |
||||
UPDATE SET balance = balance * 2, val = t.val || ' when1' |
||||
WHEN MATCHED AND balance < 200 THEN |
||||
UPDATE SET balance = balance * 4, val = t.val || ' when2' |
||||
WHEN MATCHED AND balance < 300 THEN |
||||
UPDATE SET balance = balance * 8, val = t.val || ' when3'; |
||||
} |
||||
|
||||
step "select1" { SELECT * FROM target; } |
||||
step "c1" { COMMIT; } |
||||
|
||||
session "s2" |
||||
setup |
||||
{ |
||||
BEGIN ISOLATION LEVEL READ COMMITTED; |
||||
} |
||||
step "update1" { UPDATE target t SET balance = balance + 10, val = t.val || ' updated by update1' WHERE t.key = 1; } |
||||
step "update2" { UPDATE target t SET status = 's2', val = t.val || ' updated by update2' WHERE t.key = 1; } |
||||
step "update3" { UPDATE target t SET status = 's3', val = t.val || ' updated by update3' WHERE t.key = 1; } |
||||
step "update5" { UPDATE target t SET status = 's5', val = t.val || ' updated by update5' WHERE t.key = 1; } |
||||
step "update_bal1" { UPDATE target t SET balance = 50, val = t.val || ' updated by update_bal1' WHERE t.key = 1; } |
||||
step "c2" { COMMIT; } |
||||
|
||||
# merge_status sees concurrently updated row and rechecks WHEN conditions, but recheck passes and final status = 's2' |
||||
permutation "update1" "merge_status" "c2" "select1" "c1" |
||||
|
||||
# merge_status sees concurrently updated row and rechecks WHEN conditions, recheck fails, so final status = 's3' not 's2' |
||||
permutation "update2" "merge_status" "c2" "select1" "c1" |
||||
|
||||
# merge_status sees concurrently updated row and rechecks WHEN conditions, recheck fails, so final status = 's4' not 's2' |
||||
permutation "update3" "merge_status" "c2" "select1" "c1" |
||||
|
||||
# merge_status sees concurrently updated row and rechecks WHEN conditions, recheck fails, but we skip update and MERGE does nothing |
||||
permutation "update5" "merge_status" "c2" "select1" "c1" |
||||
|
||||
# merge_bal sees concurrently updated row and rechecks WHEN conditions, recheck fails, so final balance = 100 not 640 |
||||
permutation "update_bal1" "merge_bal" "c2" "select1" "c1" |
@ -0,0 +1,156 @@ |
||||
# MERGE UPDATE |
||||
# |
||||
# This test exercises atypical cases |
||||
# 1. UPDATEs of PKs that change the join in the ON clause |
||||
# 2. UPDATEs with WHEN conditions that would fail after concurrent update |
||||
# 3. UPDATEs with extra ON conditions that would fail after concurrent update |
||||
|
||||
setup |
||||
{ |
||||
CREATE TABLE target (key int primary key, val text); |
||||
INSERT INTO target VALUES (1, 'setup1'); |
||||
|
||||
CREATE TABLE pa_target (key integer, val text) |
||||
PARTITION BY LIST (key); |
||||
CREATE TABLE part1 (key integer, val text); |
||||
CREATE TABLE part2 (val text, key integer); |
||||
CREATE TABLE part3 (key integer, val text); |
||||
|
||||
ALTER TABLE pa_target ATTACH PARTITION part1 FOR VALUES IN (1,4); |
||||
ALTER TABLE pa_target ATTACH PARTITION part2 FOR VALUES IN (2,5,6); |
||||
ALTER TABLE pa_target ATTACH PARTITION part3 DEFAULT; |
||||
|
||||
INSERT INTO pa_target VALUES (1, 'initial'); |
||||
INSERT INTO pa_target VALUES (2, 'initial'); |
||||
} |
||||
|
||||
teardown |
||||
{ |
||||
DROP TABLE target; |
||||
DROP TABLE pa_target CASCADE; |
||||
} |
||||
|
||||
session "s1" |
||||
setup |
||||
{ |
||||
BEGIN ISOLATION LEVEL READ COMMITTED; |
||||
} |
||||
step "merge1" |
||||
{ |
||||
MERGE INTO target t |
||||
USING (SELECT 1 as key, 'merge1' as val) s |
||||
ON s.key = t.key |
||||
WHEN NOT MATCHED THEN |
||||
INSERT VALUES (s.key, s.val) |
||||
WHEN MATCHED THEN |
||||
UPDATE set key = t.key + 1, val = t.val || ' updated by ' || s.val; |
||||
} |
||||
step "pa_merge1" |
||||
{ |
||||
MERGE INTO pa_target t |
||||
USING (SELECT 1 as key, 'pa_merge1' as val) s |
||||
ON s.key = t.key |
||||
WHEN NOT MATCHED THEN |
||||
INSERT VALUES (s.key, s.val) |
||||
WHEN MATCHED THEN |
||||
UPDATE set val = t.val || ' updated by ' || s.val; |
||||
} |
||||
step "pa_merge2" |
||||
{ |
||||
MERGE INTO pa_target t |
||||
USING (SELECT 1 as key, 'pa_merge2' as val) s |
||||
ON s.key = t.key |
||||
WHEN NOT MATCHED THEN |
||||
INSERT VALUES (s.key, s.val) |
||||
WHEN MATCHED THEN |
||||
UPDATE set key = t.key + 1, val = t.val || ' updated by ' || s.val; |
||||
} |
||||
step "pa_merge3" |
||||
{ |
||||
MERGE INTO pa_target t |
||||
USING (SELECT 1 as key, 'pa_merge2' as val) s |
||||
ON s.key = t.key |
||||
WHEN NOT MATCHED THEN |
||||
INSERT VALUES (s.key, s.val) |
||||
WHEN MATCHED THEN |
||||
UPDATE set val = 'prefix ' || t.val; |
||||
} |
||||
step "c1" { COMMIT; } |
||||
step "a1" { ABORT; } |
||||
|
||||
session "s2" |
||||
setup |
||||
{ |
||||
BEGIN ISOLATION LEVEL READ COMMITTED; |
||||
} |
||||
step "merge2a" |
||||
{ |
||||
MERGE INTO target t |
||||
USING (SELECT 1 as key, 'merge2a' as val) s |
||||
ON s.key = t.key |
||||
WHEN NOT MATCHED THEN |
||||
INSERT VALUES (s.key, s.val) |
||||
WHEN MATCHED THEN |
||||
UPDATE set key = t.key + 1, val = t.val || ' updated by ' || s.val; |
||||
} |
||||
step "merge2b" |
||||
{ |
||||
MERGE INTO target t |
||||
USING (SELECT 1 as key, 'merge2b' as val) s |
||||
ON s.key = t.key |
||||
WHEN NOT MATCHED THEN |
||||
INSERT VALUES (s.key, s.val) |
||||
WHEN MATCHED AND t.key < 2 THEN |
||||
UPDATE set key = t.key + 1, val = t.val || ' updated by ' || s.val; |
||||
} |
||||
step "merge2c" |
||||
{ |
||||
MERGE INTO target t |
||||
USING (SELECT 1 as key, 'merge2c' as val) s |
||||
ON s.key = t.key AND t.key < 2 |
||||
WHEN NOT MATCHED THEN |
||||
INSERT VALUES (s.key, s.val) |
||||
WHEN MATCHED THEN |
||||
UPDATE set key = t.key + 1, val = t.val || ' updated by ' || s.val; |
||||
} |
||||
step "pa_merge2a" |
||||
{ |
||||
MERGE INTO pa_target t |
||||
USING (SELECT 1 as key, 'pa_merge2a' as val) s |
||||
ON s.key = t.key |
||||
WHEN NOT MATCHED THEN |
||||
INSERT VALUES (s.key, s.val) |
||||
WHEN MATCHED THEN |
||||
UPDATE set key = t.key + 1, val = t.val || ' updated by ' || s.val; |
||||
} |
||||
# MERGE proceeds only if 'val' unchanged |
||||
step "pa_merge2b_when" |
||||
{ |
||||
MERGE INTO pa_target t |
||||
USING (SELECT 1 as key, 'pa_merge2b_when' as val) s |
||||
ON s.key = t.key |
||||
WHEN NOT MATCHED THEN |
||||
INSERT VALUES (s.key, s.val) |
||||
WHEN MATCHED AND t.val like 'initial%' THEN |
||||
UPDATE set key = t.key + 1, val = t.val || ' updated by ' || s.val; |
||||
} |
||||
step "select2" { SELECT * FROM target; } |
||||
step "pa_select2" { SELECT * FROM pa_target; } |
||||
step "c2" { COMMIT; } |
||||
|
||||
# Basic effects |
||||
permutation "merge1" "c1" "select2" "c2" |
||||
|
||||
# One after the other, no concurrency |
||||
permutation "merge1" "c1" "merge2a" "select2" "c2" |
||||
|
||||
# Now with concurrency |
||||
permutation "merge1" "merge2a" "c1" "select2" "c2" |
||||
permutation "merge1" "merge2a" "a1" "select2" "c2" |
||||
permutation "merge1" "merge2b" "c1" "select2" "c2" |
||||
permutation "merge1" "merge2c" "c1" "select2" "c2" |
||||
permutation "pa_merge1" "pa_merge2a" "c1" "pa_select2" "c2" |
||||
permutation "pa_merge2" "pa_merge2a" "c1" "pa_select2" "c2" # fails |
||||
permutation "pa_merge2" "c1" "pa_merge2a" "pa_select2" "c2" # succeeds |
||||
permutation "pa_merge3" "pa_merge2b_when" "c1" "pa_select2" "c2" # WHEN not satisfied by updated tuple |
||||
permutation "pa_merge1" "pa_merge2b_when" "c1" "pa_select2" "c2" # WHEN satisfied by updated tuple |
File diff suppressed because it is too large
Load Diff
File diff suppressed because it is too large
Load Diff
Loading…
Reference in new issue