mirror of https://github.com/postgres/postgres
parent
d204ef6377
commit
83454e3c2b
@ -0,0 +1,603 @@ |
||||
<!-- |
||||
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>insert, update, or delete rows of a table based upon source data</refpurpose> |
||||
</refnamediv> |
||||
|
||||
<refsynopsisdiv> |
||||
<synopsis> |
||||
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> [...] |
||||
|
||||
where <replaceable class="parameter">data_source</replaceable> is |
||||
|
||||
{ <replaceable class="parameter">source_table_name</replaceable> | |
||||
( source_query ) |
||||
} |
||||
[ [ AS ] <replaceable class="parameter">source_alias</replaceable> ] |
||||
|
||||
and <replaceable class="parameter">when_clause</replaceable> is |
||||
|
||||
{ WHEN MATCHED [ AND <replaceable class="parameter">condition</replaceable> ] THEN { <replaceable class="parameter">merge_update</replaceable> | <replaceable class="parameter">merge_delete</replaceable> } | |
||||
WHEN NOT MATCHED [ AND <replaceable class="parameter">condition</replaceable> ] THEN { <replaceable class="parameter">merge_insert</replaceable> | DO NOTHING } |
||||
} |
||||
|
||||
and <replaceable class="parameter">merge_insert</replaceable> is |
||||
|
||||
INSERT [( <replaceable class="parameter">column_name</replaceable> [, ...] )] |
||||
[ OVERRIDING { SYSTEM | USER } VALUE ] |
||||
{ VALUES ( { <replaceable class="parameter">expression</replaceable> | DEFAULT } [, ...] ) | DEFAULT VALUES } |
||||
|
||||
and <replaceable class="parameter">merge_update</replaceable> is |
||||
|
||||
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 } [, ...] ) |
||||
} [, ...] |
||||
|
||||
and <replaceable class="parameter">merge_delete</replaceable> is |
||||
|
||||
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. If one of them is activated, the specified |
||||
action occurs. No more than one <literal>WHEN</literal> clause can be |
||||
activated 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 tablename 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> action is specified, the source row is |
||||
skipped. Since actions are evaluated in the given order, <literal>DO |
||||
NOTHING</literal> can be handy to skip non-interesting source rows before |
||||
more fine-grained handling. |
||||
</para> |
||||
|
||||
<para> |
||||
There is no MERGE privilege. |
||||
You must have the <literal>UPDATE</literal> privilege on the column(s) |
||||
of the <replaceable class="parameter">target_table_name</replaceable> |
||||
referred to in the <literal>SET</literal> clause |
||||
if you specify an update action, the <literal>INSERT</literal> privilege |
||||
on the <replaceable class="parameter">target_table_name</replaceable> |
||||
if you specify an insert action and/or the <literal>DELETE</literal> |
||||
privilege on the <replaceable class="parameter">target_table_name</replaceable> |
||||
if you specify a delete action 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 activated |
||||
during the subsequent execution. |
||||
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> |
||||
MERGE is not supported if the <replaceable |
||||
class="parameter">target_table_name</replaceable> has |
||||
<literal>RULES</literal> defined on it. |
||||
See <xref linkend="rules"/> for more information about <literal>RULES</literal>. |
||||
</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 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 whether table or query was specified. |
||||
</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 only 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 activated if the |
||||
<replaceable class="parameter">condition</replaceable> is |
||||
absent or is present and evaluates to <literal>true</literal>. |
||||
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 activated if the |
||||
<replaceable class="parameter">condition</replaceable> is |
||||
absent or is present and 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 returns <literal>true</literal> then the <literal>WHEN</literal> |
||||
clause will be activated and the corresponding action will occur for |
||||
that row. The expression may not contain functions that possibly performs |
||||
writes to the database. |
||||
</para> |
||||
<para> |
||||
A condition on a <literal>WHEN MATCHED</literal> clause can refer to columns |
||||
in both the source and the target relation. 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 one of the input rows 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> |
||||
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> |
||||
Do not include the table name, as you would normally do with an |
||||
<xref linkend="sql-update"/> command. |
||||
For example, <literal>UPDATE tab SET col = 1</literal> is invalid. Also, |
||||
do not include a <literal>WHERE</literal> clause, since only the current |
||||
row can be updated. For example, |
||||
<literal>UPDATE SET col = 1 WHERE key = 57</literal> is invalid. |
||||
</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 tablename or any other clauses, as you would normally |
||||
do with an <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.) When referencing a |
||||
column, 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. The expression can use the |
||||
old values of this and other columns in the table. |
||||
</para> |
||||
</listitem> |
||||
</varlistentry> |
||||
|
||||
<varlistentry> |
||||
<term><literal>DEFAULT</literal></term> |
||||
<listitem> |
||||
<para> |
||||
Set the column to its default value (which will be NULL if no |
||||
specific default expression has been assigned to it). |
||||
</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>Execution</title> |
||||
|
||||
<para> |
||||
The following steps take place during the execution of |
||||
<command>MERGE</command>. |
||||
<orderedlist> |
||||
<listitem> |
||||
<para> |
||||
Perform any BEFORE STATEMENT triggers for all actions specified, whether or |
||||
not their <literal>WHEN</literal> clauses are activated during execution. |
||||
</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 row. For each candidate change row |
||||
<orderedlist> |
||||
<listitem> |
||||
<para> |
||||
Evaluate whether each row is MATCHED or NOT MATCHED. |
||||
</para> |
||||
</listitem> |
||||
<listitem> |
||||
<para> |
||||
Test each WHEN condition in the order specified until one activates. |
||||
</para> |
||||
</listitem> |
||||
<listitem> |
||||
<para> |
||||
When activated, perform the following actions |
||||
<orderedlist> |
||||
<listitem> |
||||
<para> |
||||
Perform any BEFORE ROW triggers that fire for the action's event type. |
||||
</para> |
||||
</listitem> |
||||
<listitem> |
||||
<para> |
||||
Apply the action specified, invoking any check constraints on the |
||||
target table. |
||||
However, it will not invoke rules. |
||||
</para> |
||||
</listitem> |
||||
<listitem> |
||||
<para> |
||||
Perform any AFTER ROW triggers that fire for the action's event type. |
||||
</para> |
||||
</listitem> |
||||
</orderedlist> |
||||
</para> |
||||
</listitem> |
||||
</orderedlist> |
||||
</para> |
||||
</listitem> |
||||
<listitem> |
||||
<para> |
||||
Perform any AFTER STATEMENT 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, INSERT) will |
||||
be fired whenever we <emphasis>specify</emphasis> an action of that kind. Row-level |
||||
triggers will fire only for the one event type <emphasis>activated</emphasis>. |
||||
So a <command>MERGE</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 will |
||||
cause an error. This can also occur if row triggers make changes to the |
||||
target table which are then subsequently 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 are simply ignored. |
||||
</para> |
||||
|
||||
<para> |
||||
If a <literal>WHEN</literal> clause omits an <literal>AND</literal> 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 a final reachable clause is omitted it is possible that no action |
||||
will be taken for a candidate change row. |
||||
</para> |
||||
|
||||
</refsect1> |
||||
<refsect1> |
||||
<title>Notes</title> |
||||
|
||||
<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> |
||||
|
||||
<tip> |
||||
<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> |
||||
</tip> |
||||
</refsect1> |
||||
|
||||
<refsect1> |
||||
<title>Examples</title> |
||||
|
||||
<para> |
||||
Perform maintenance on CustomerAccounts based upon new Transactions. |
||||
|
||||
<programlisting> |
||||
MERGE 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> |
||||
|
||||
notice that this would be exactly equivalent to the following |
||||
statement because the <literal>MATCHED</literal> result does not change |
||||
during execution |
||||
|
||||
<programlisting> |
||||
MERGE 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 wine_stock_changes 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 DO NOTHING action is an extension to the <acronym>SQL</acronym> standard. |
||||
</para> |
||||
</refsect1> |
||||
</refentry> |
@ -0,0 +1,575 @@ |
||||
/*-------------------------------------------------------------------------
|
||||
* |
||||
* nodeMerge.c |
||||
* routines to handle Merge nodes relating to the MERGE command |
||||
* |
||||
* Portions Copyright (c) 1996-2018, PostgreSQL Global Development Group |
||||
* Portions Copyright (c) 1994, Regents of the University of California |
||||
* |
||||
* |
||||
* IDENTIFICATION |
||||
* src/backend/executor/nodeMerge.c |
||||
* |
||||
*------------------------------------------------------------------------- |
||||
*/ |
||||
|
||||
|
||||
#include "postgres.h" |
||||
|
||||
#include "access/htup_details.h" |
||||
#include "access/xact.h" |
||||
#include "commands/trigger.h" |
||||
#include "executor/execPartition.h" |
||||
#include "executor/executor.h" |
||||
#include "executor/nodeModifyTable.h" |
||||
#include "executor/nodeMerge.h" |
||||
#include "miscadmin.h" |
||||
#include "nodes/nodeFuncs.h" |
||||
#include "storage/bufmgr.h" |
||||
#include "storage/lmgr.h" |
||||
#include "utils/builtins.h" |
||||
#include "utils/memutils.h" |
||||
#include "utils/rel.h" |
||||
#include "utils/tqual.h" |
||||
|
||||
|
||||
/*
|
||||
* Check and execute the first qualifying MATCHED action. The current target |
||||
* tuple is identified by tupleid. |
||||
* |
||||
* We start from the first WHEN MATCHED action and check if the WHEN AND quals |
||||
* pass, if any. If the WHEN AND quals for the first action do not pass, we |
||||
* check the second, then the third and so on. If we reach to the end, no |
||||
* action is taken and we return true, indicating that no further action is |
||||
* required for this tuple. |
||||
* |
||||
* If we do find a qualifying action, then we attempt to execute the action. |
||||
* |
||||
* If the tuple is concurrently updated, EvalPlanQual is run with the updated |
||||
* tuple to recheck the join quals. Note that the additional quals associated |
||||
* with individual actions are evaluated separately by the MERGE code, while |
||||
* EvalPlanQual checks for the join quals. If EvalPlanQual tells us that the |
||||
* updated tuple still passes the join quals, then we restart from the first |
||||
* action to look for a qualifying action. Otherwise, we return false meaning |
||||
* that a NOT MATCHED action must now be executed for the current source tuple. |
||||
*/ |
||||
static bool |
||||
ExecMergeMatched(ModifyTableState *mtstate, EState *estate, |
||||
TupleTableSlot *slot, JunkFilter *junkfilter, |
||||
ItemPointer tupleid) |
||||
{ |
||||
ExprContext *econtext = mtstate->ps.ps_ExprContext; |
||||
bool isNull; |
||||
List *mergeMatchedActionStates = NIL; |
||||
HeapUpdateFailureData hufd; |
||||
bool tuple_updated, |
||||
tuple_deleted; |
||||
Buffer buffer; |
||||
HeapTupleData tuple; |
||||
EPQState *epqstate = &mtstate->mt_epqstate; |
||||
ResultRelInfo *saved_resultRelInfo; |
||||
ResultRelInfo *resultRelInfo = estate->es_result_relation_info; |
||||
ListCell *l; |
||||
TupleTableSlot *saved_slot = slot; |
||||
|
||||
if (mtstate->mt_partition_tuple_routing) |
||||
{ |
||||
Datum datum; |
||||
Oid tableoid = InvalidOid; |
||||
int leaf_part_index; |
||||
PartitionTupleRouting *proute = mtstate->mt_partition_tuple_routing; |
||||
|
||||
/*
|
||||
* In case of partitioned table, we fetch the tableoid while performing |
||||
* MATCHED MERGE action. |
||||
*/ |
||||
datum = ExecGetJunkAttribute(slot, junkfilter->jf_otherJunkAttNo, |
||||
&isNull); |
||||
Assert(!isNull); |
||||
tableoid = DatumGetObjectId(datum); |
||||
|
||||
/*
|
||||
* If we're dealing with a MATCHED tuple, then tableoid must have been |
||||
* set correctly. In case of partitioned table, we must now fetch the |
||||
* correct result relation corresponding to the child table emitting |
||||
* the matching target row. For normal table, there is just one result |
||||
* relation and it must be the one emitting the matching row. |
||||
*/ |
||||
leaf_part_index = ExecFindPartitionByOid(proute, tableoid); |
||||
|
||||
resultRelInfo = proute->partitions[leaf_part_index]; |
||||
if (resultRelInfo == NULL) |
||||
{ |
||||
resultRelInfo = ExecInitPartitionInfo(mtstate, |
||||
mtstate->resultRelInfo, |
||||
proute, estate, leaf_part_index); |
||||
Assert(resultRelInfo != NULL); |
||||
} |
||||
} |
||||
|
||||
/*
|
||||
* Save the current information and work with the correct result relation. |
||||
*/ |
||||
saved_resultRelInfo = resultRelInfo; |
||||
estate->es_result_relation_info = resultRelInfo; |
||||
|
||||
/*
|
||||
* And get the correct action lists. |
||||
*/ |
||||
mergeMatchedActionStates = |
||||
resultRelInfo->ri_mergeState->matchedActionStates; |
||||
|
||||
/*
|
||||
* If there are not WHEN MATCHED actions, we are done. |
||||
*/ |
||||
if (mergeMatchedActionStates == NIL) |
||||
return true; |
||||
|
||||
/*
|
||||
* Make tuple and any needed join variables available to ExecQual and |
||||
* ExecProject. The target's existing tuple is installed in the scantuple. |
||||
* Again, this target relation's slot is required only in the case of a |
||||
* MATCHED tuple and UPDATE/DELETE actions. |
||||
*/ |
||||
if (mtstate->mt_partition_tuple_routing) |
||||
ExecSetSlotDescriptor(mtstate->mt_existing, |
||||
resultRelInfo->ri_RelationDesc->rd_att); |
||||
econtext->ecxt_scantuple = mtstate->mt_existing; |
||||
econtext->ecxt_innertuple = slot; |
||||
econtext->ecxt_outertuple = NULL; |
||||
|
||||
lmerge_matched:; |
||||
slot = saved_slot; |
||||
|
||||
/*
|
||||
* UPDATE/DELETE is only invoked for matched rows. And we must have found |
||||
* the tupleid of the target row in that case. We fetch using SnapshotAny |
||||
* because we might get called again after EvalPlanQual returns us a new |
||||
* tuple. This tuple may not be visible to our MVCC snapshot. |
||||
*/ |
||||
Assert(tupleid != NULL); |
||||
|
||||
tuple.t_self = *tupleid; |
||||
if (!heap_fetch(resultRelInfo->ri_RelationDesc, SnapshotAny, &tuple, |
||||
&buffer, true, NULL)) |
||||
elog(ERROR, "Failed to fetch the target tuple"); |
||||
|
||||
/* Store target's existing tuple in the state's dedicated slot */ |
||||
ExecStoreTuple(&tuple, mtstate->mt_existing, buffer, false); |
||||
|
||||
foreach(l, mergeMatchedActionStates) |
||||
{ |
||||
MergeActionState *action = (MergeActionState *) lfirst(l); |
||||
|
||||
/*
|
||||
* Test condition, if any |
||||
* |
||||
* In the absence of a condition we perform the action unconditionally |
||||
* (no need to check separately since ExecQual() will return true if |
||||
* there are no conditions to evaluate). |
||||
*/ |
||||
if (!ExecQual(action->whenqual, econtext)) |
||||
continue; |
||||
|
||||
/*
|
||||
* Check if the existing target tuple meet the USING checks of |
||||
* UPDATE/DELETE RLS policies. If those checks fail, we throw an |
||||
* error. |
||||
* |
||||
* The WITH CHECK quals are applied in ExecUpdate() and hence we need |
||||
* not do anything special to handle them. |
||||
* |
||||
* NOTE: We must do this after WHEN quals are evaluated so that we |
||||
* check policies only when they matter. |
||||
*/ |
||||
if (resultRelInfo->ri_WithCheckOptions) |
||||
{ |
||||
ExecWithCheckOptions(action->commandType == CMD_UPDATE ? |
||||
WCO_RLS_MERGE_UPDATE_CHECK : WCO_RLS_MERGE_DELETE_CHECK, |
||||
resultRelInfo, |
||||
mtstate->mt_existing, |
||||
mtstate->ps.state); |
||||
} |
||||
|
||||
/* Perform stated action */ |
||||
switch (action->commandType) |
||||
{ |
||||
case CMD_UPDATE: |
||||
|
||||
/*
|
||||
* We set up the projection earlier, so all we do here is |
||||
* Project, no need for any other tasks prior to the |
||||
* ExecUpdate. |
||||
*/ |
||||
if (mtstate->mt_partition_tuple_routing) |
||||
ExecSetSlotDescriptor(mtstate->mt_mergeproj, action->tupDesc); |
||||
ExecProject(action->proj); |
||||
|
||||
/*
|
||||
* We don't call ExecFilterJunk() because the projected tuple |
||||
* using the UPDATE action's targetlist doesn't have a junk |
||||
* attribute. |
||||
*/ |
||||
slot = ExecUpdate(mtstate, tupleid, NULL, |
||||
mtstate->mt_mergeproj, |
||||
slot, epqstate, estate, |
||||
&tuple_updated, &hufd, |
||||
action, mtstate->canSetTag); |
||||
break; |
||||
|
||||
case CMD_DELETE: |
||||
/* Nothing to Project for a DELETE action */ |
||||
slot = ExecDelete(mtstate, tupleid, NULL, |
||||
slot, epqstate, estate, |
||||
&tuple_deleted, false, &hufd, action, |
||||
mtstate->canSetTag); |
||||
|
||||
break; |
||||
|
||||
default: |
||||
elog(ERROR, "unknown action in MERGE WHEN MATCHED clause"); |
||||
|
||||
} |
||||
|
||||
/*
|
||||
* Check for any concurrent update/delete operation which may have |
||||
* prevented our update/delete. We also check for situations where we |
||||
* might be trying to update/delete the same tuple twice. |
||||
*/ |
||||
if ((action->commandType == CMD_UPDATE && !tuple_updated) || |
||||
(action->commandType == CMD_DELETE && !tuple_deleted)) |
||||
|
||||
{ |
||||
switch (hufd.result) |
||||
{ |
||||
case HeapTupleMayBeUpdated: |
||||
break; |
||||
case HeapTupleInvisible: |
||||
|
||||
/*
|
||||
* This state should never be reached since the underlying |
||||
* JOIN runs with a MVCC snapshot and should only return |
||||
* rows visible to us. |
||||
*/ |
||||
elog(ERROR, "unexpected invisible tuple"); |
||||
break; |
||||
|
||||
case HeapTupleSelfUpdated: |
||||
|
||||
/*
|
||||
* SQLStandard disallows this for MERGE. |
||||
*/ |
||||
if (TransactionIdIsCurrentTransactionId(hufd.xmax)) |
||||
ereport(ERROR, |
||||
(errcode(ERRCODE_CARDINALITY_VIOLATION), |
||||
errmsg("MERGE command cannot affect row a second time"), |
||||
errhint("Ensure that not more than one source row matches any one target row"))); |
||||
/* This shouldn't happen */ |
||||
elog(ERROR, "attempted to update or delete invisible tuple"); |
||||
break; |
||||
|
||||
case HeapTupleUpdated: |
||||
|
||||
/*
|
||||
* The target tuple was concurrently updated/deleted by |
||||
* some other transaction. |
||||
* |
||||
* If the current tuple is that last tuple in the update |
||||
* chain, then we know that the tuple was concurrently |
||||
* deleted. Just return and let the caller try NOT MATCHED |
||||
* actions. |
||||
* |
||||
* If the current tuple was concurrently updated, then we |
||||
* must run the EvalPlanQual() with the new version of the |
||||
* tuple. If EvalPlanQual() does not return a tuple then |
||||
* we switch to the NOT MATCHED list of actions. |
||||
* If it does return a tuple and the join qual is |
||||
* still satisfied, then we just need to recheck the |
||||
* MATCHED actions, starting from the top, and execute the |
||||
* first qualifying action. |
||||
*/ |
||||
if (!ItemPointerEquals(tupleid, &hufd.ctid)) |
||||
{ |
||||
TupleTableSlot *epqslot; |
||||
|
||||
/*
|
||||
* Since we generate a JOIN query with a target table |
||||
* RTE different than the result relation RTE, we must |
||||
* pass in the RTI of the relation used in the join |
||||
* query and not the one from result relation. |
||||
*/ |
||||
Assert(resultRelInfo->ri_mergeTargetRTI > 0); |
||||
epqslot = EvalPlanQual(estate, |
||||
epqstate, |
||||
resultRelInfo->ri_RelationDesc, |
||||
GetEPQRangeTableIndex(resultRelInfo), |
||||
LockTupleExclusive, |
||||
&hufd.ctid, |
||||
hufd.xmax); |
||||
|
||||
if (!TupIsNull(epqslot)) |
||||
{ |
||||
(void) ExecGetJunkAttribute(epqslot, |
||||
resultRelInfo->ri_junkFilter->jf_junkAttNo, |
||||
&isNull); |
||||
|
||||
/*
|
||||
* A non-NULL ctid means that we are still dealing |
||||
* with MATCHED case. But we must retry from the |
||||
* start with the updated tuple to ensure that the |
||||
* first qualifying WHEN MATCHED action is |
||||
* executed. |
||||
* |
||||
* We don't use the new slot returned by |
||||
* EvalPlanQual because we anyways re-install the |
||||
* new target tuple in econtext->ecxt_scantuple |
||||
* before re-evaluating WHEN AND conditions and |
||||
* re-projecting the update targetlists. The |
||||
* source side tuple does not change and hence we |
||||
* can safely continue to use the old slot. |
||||
*/ |
||||
if (!isNull) |
||||
{ |
||||
/*
|
||||
* Must update *tupleid to the TID of the |
||||
* newer tuple found in the update chain. |
||||
*/ |
||||
*tupleid = hufd.ctid; |
||||
ReleaseBuffer(buffer); |
||||
goto lmerge_matched; |
||||
} |
||||
} |
||||
} |
||||
|
||||
/*
|
||||
* Tell the caller about the updated TID, restore the |
||||
* state back and return. |
||||
*/ |
||||
*tupleid = hufd.ctid; |
||||
estate->es_result_relation_info = saved_resultRelInfo; |
||||
ReleaseBuffer(buffer); |
||||
return false; |
||||
|
||||
default: |
||||
break; |
||||
|
||||
} |
||||
} |
||||
|
||||
if (action->commandType == CMD_UPDATE && tuple_updated) |
||||
InstrCountFiltered2(&mtstate->ps, 1); |
||||
if (action->commandType == CMD_DELETE && tuple_deleted) |
||||
InstrCountFiltered3(&mtstate->ps, 1); |
||||
|
||||
/*
|
||||
* We've activated one of the WHEN clauses, so we don't search |
||||
* further. This is required behaviour, not an optimization. |
||||
*/ |
||||
estate->es_result_relation_info = saved_resultRelInfo; |
||||
break; |
||||
} |
||||
|
||||
ReleaseBuffer(buffer); |
||||
|
||||
/*
|
||||
* Successfully executed an action or no qualifying action was found. |
||||
*/ |
||||
return true; |
||||
} |
||||
|
||||
/*
|
||||
* Execute the first qualifying NOT MATCHED action. |
||||
*/ |
||||
static void |
||||
ExecMergeNotMatched(ModifyTableState *mtstate, EState *estate, |
||||
TupleTableSlot *slot) |
||||
{ |
||||
PartitionTupleRouting *proute = mtstate->mt_partition_tuple_routing; |
||||
ExprContext *econtext = mtstate->ps.ps_ExprContext; |
||||
List *mergeNotMatchedActionStates = NIL; |
||||
ResultRelInfo *resultRelInfo; |
||||
ListCell *l; |
||||
TupleTableSlot *myslot; |
||||
|
||||
/*
|
||||
* We are dealing with NOT MATCHED tuple. Since for MERGE, partition tree |
||||
* is not expanded for the result relation, we continue to work with the |
||||
* currently active result relation, which should be of the root of the |
||||
* partition tree. |
||||
*/ |
||||
resultRelInfo = mtstate->resultRelInfo; |
||||
|
||||
/*
|
||||
* For INSERT actions, root relation's merge action is OK since the |
||||
* INSERT's targetlist and the WHEN conditions can only refer to the |
||||
* source relation and hence it does not matter which result relation we |
||||
* work with. |
||||
*/ |
||||
mergeNotMatchedActionStates = |
||||
resultRelInfo->ri_mergeState->notMatchedActionStates; |
||||
|
||||
/*
|
||||
* Make source tuple available to ExecQual and ExecProject. We don't need |
||||
* the target tuple since the WHEN quals and the targetlist can't refer to |
||||
* the target columns. |
||||
*/ |
||||
econtext->ecxt_scantuple = NULL; |
||||
econtext->ecxt_innertuple = slot; |
||||
econtext->ecxt_outertuple = NULL; |
||||
|
||||
foreach(l, mergeNotMatchedActionStates) |
||||
{ |
||||
MergeActionState *action = (MergeActionState *) lfirst(l); |
||||
|
||||
/*
|
||||
* Test condition, if any |
||||
* |
||||
* In the absence of a condition we perform the action unconditionally |
||||
* (no need to check separately since ExecQual() will return true if |
||||
* there are no conditions to evaluate). |
||||
*/ |
||||
if (!ExecQual(action->whenqual, econtext)) |
||||
continue; |
||||
|
||||
/* Perform stated action */ |
||||
switch (action->commandType) |
||||
{ |
||||
case CMD_INSERT: |
||||
|
||||
/*
|
||||
* We set up the projection earlier, so all we do here is |
||||
* Project, no need for any other tasks prior to the |
||||
* ExecInsert. |
||||
*/ |
||||
if (mtstate->mt_partition_tuple_routing) |
||||
ExecSetSlotDescriptor(mtstate->mt_mergeproj, action->tupDesc); |
||||
ExecProject(action->proj); |
||||
|
||||
/*
|
||||
* ExecPrepareTupleRouting may modify the passed-in slot. Hence |
||||
* pass a local reference so that action->slot is not modified. |
||||
*/ |
||||
myslot = mtstate->mt_mergeproj; |
||||
|
||||
/* Prepare for tuple routing if needed. */ |
||||
if (proute) |
||||
myslot = ExecPrepareTupleRouting(mtstate, estate, proute, |
||||
resultRelInfo, myslot); |
||||
slot = ExecInsert(mtstate, myslot, slot, |
||||
estate, action, |
||||
mtstate->canSetTag); |
||||
/* Revert ExecPrepareTupleRouting's state change. */ |
||||
if (proute) |
||||
estate->es_result_relation_info = resultRelInfo; |
||||
InstrCountFiltered1(&mtstate->ps, 1); |
||||
break; |
||||
case CMD_NOTHING: |
||||
/* Do Nothing */ |
||||
break; |
||||
default: |
||||
elog(ERROR, "unknown action in MERGE WHEN NOT MATCHED clause"); |
||||
} |
||||
|
||||
break; |
||||
} |
||||
} |
||||
|
||||
/*
|
||||
* Perform MERGE. |
||||
*/ |
||||
void |
||||
ExecMerge(ModifyTableState *mtstate, EState *estate, TupleTableSlot *slot, |
||||
JunkFilter *junkfilter, ResultRelInfo *resultRelInfo) |
||||
{ |
||||
ExprContext *econtext = mtstate->ps.ps_ExprContext; |
||||
ItemPointer tupleid; |
||||
ItemPointerData tuple_ctid; |
||||
bool matched = false; |
||||
char relkind; |
||||
Datum datum; |
||||
bool isNull; |
||||
|
||||
relkind = resultRelInfo->ri_RelationDesc->rd_rel->relkind; |
||||
Assert(relkind == RELKIND_RELATION || |
||||
relkind == RELKIND_PARTITIONED_TABLE); |
||||
|
||||
/*
|
||||
* Reset per-tuple memory context to free any expression evaluation |
||||
* storage allocated in the previous cycle. |
||||
*/ |
||||
ResetExprContext(econtext); |
||||
|
||||
/*
|
||||
* We run a JOIN between the target relation and the source relation to |
||||
* find a set of candidate source rows that has matching row in the target |
||||
* table and a set of candidate source rows that does not have matching |
||||
* row in the target table. If the join returns us a tuple with target |
||||
* relation's tid set, that implies that the join found a matching row for |
||||
* the given source tuple. This case triggers the WHEN MATCHED clause of |
||||
* the MERGE. Whereas a NULL in the target relation's ctid column |
||||
* indicates a NOT MATCHED case. |
||||
*/ |
||||
datum = ExecGetJunkAttribute(slot, junkfilter->jf_junkAttNo, &isNull); |
||||
|
||||
if (!isNull) |
||||
{ |
||||
matched = true; |
||||
tupleid = (ItemPointer) DatumGetPointer(datum); |
||||
tuple_ctid = *tupleid; /* be sure we don't free ctid!! */ |
||||
tupleid = &tuple_ctid; |
||||
} |
||||
else |
||||
{ |
||||
matched = false; |
||||
tupleid = NULL; /* we don't need it for INSERT actions */ |
||||
} |
||||
|
||||
/*
|
||||
* If we are dealing with a WHEN MATCHED case, we execute the first action |
||||
* for which the additional WHEN MATCHED AND quals pass. If an action |
||||
* without quals is found, that action is executed. |
||||
* |
||||
* Similarly, if we are dealing with WHEN NOT MATCHED case, we look at the |
||||
* given WHEN NOT MATCHED actions in sequence until one passes. |
||||
* |
||||
* Things get interesting in case of concurrent update/delete of the |
||||
* target tuple. Such concurrent update/delete is detected while we are |
||||
* executing a WHEN MATCHED action. |
||||
* |
||||
* A concurrent update can: |
||||
* |
||||
* 1. modify the target tuple so that it no longer satisfies the |
||||
* additional quals attached to the current WHEN MATCHED action OR |
||||
* |
||||
* In this case, we are still dealing with a WHEN MATCHED case, but |
||||
* we should recheck the list of WHEN MATCHED actions and choose the first |
||||
* one that satisfies the new target tuple. |
||||
* |
||||
* 2. modify the target tuple so that the join quals no longer pass and |
||||
* hence the source tuple no longer has a match. |
||||
* |
||||
* In the second case, the source tuple no longer matches the target tuple, |
||||
* so we now instead find a qualifying WHEN NOT MATCHED action to execute. |
||||
* |
||||
* A concurrent delete, changes a WHEN MATCHED case to WHEN NOT MATCHED. |
||||
* |
||||
* ExecMergeMatched takes care of following the update chain and |
||||
* re-finding the qualifying WHEN MATCHED action, as long as the updated |
||||
* target tuple still satisfies the join quals i.e. it still remains a |
||||
* WHEN MATCHED case. If the tuple gets deleted or the join quals fail, it |
||||
* returns and we try ExecMergeNotMatched. Given that ExecMergeMatched |
||||
* always make progress by following the update chain and we never switch |
||||
* from ExecMergeNotMatched to ExecMergeMatched, there is no risk of a |
||||
* livelock. |
||||
*/ |
||||
if (matched) |
||||
matched = ExecMergeMatched(mtstate, estate, slot, junkfilter, tupleid); |
||||
|
||||
/*
|
||||
* Either we were dealing with a NOT MATCHED tuple or ExecMergeNotMatched() |
||||
* returned "false", indicating the previously MATCHED tuple is no longer a |
||||
* matching tuple. |
||||
*/ |
||||
if (!matched) |
||||
ExecMergeNotMatched(mtstate, estate, slot); |
||||
} |
@ -0,0 +1,660 @@ |
||||
/*-------------------------------------------------------------------------
|
||||
* |
||||
* parse_merge.c |
||||
* handle merge-statement in parser |
||||
* |
||||
* Portions Copyright (c) 1996-2018, 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 "miscadmin.h" |
||||
|
||||
#include "access/sysattr.h" |
||||
#include "nodes/makefuncs.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_merge.h" |
||||
#include "parser/parse_relation.h" |
||||
#include "parser/parse_target.h" |
||||
#include "utils/rel.h" |
||||
#include "utils/relcache.h" |
||||
|
||||
static int transformMergeJoinClause(ParseState *pstate, Node *merge, |
||||
List **mergeSourceTargetList); |
||||
static void setNamespaceForMergeAction(ParseState *pstate, |
||||
MergeAction *action); |
||||
static void setNamespaceVisibilityForRTE(List *namespace, RangeTblEntry *rte, |
||||
bool rel_visible, |
||||
bool cols_visible); |
||||
static List *expandSourceTL(ParseState *pstate, RangeTblEntry *rte, |
||||
int rtindex); |
||||
|
||||
/*
|
||||
* Special handling for MERGE statement is required because we assemble |
||||
* the query manually. This is similar to setTargetTable() followed |
||||
* by transformFromClause() but with a few less steps. |
||||
* |
||||
* Process the FROM clause and add items to the query's range table, |
||||
* joinlist, and namespace. |
||||
* |
||||
* A special targetlist comprising of the columns from the right-subtree of |
||||
* the join is populated and returned. Note that when the JoinExpr is |
||||
* setup by transformMergeStmt, the left subtree has the target result |
||||
* relation and the right subtree has the source relation. |
||||
* |
||||
* Returns the rangetable index of the target relation. |
||||
*/ |
||||
static int |
||||
transformMergeJoinClause(ParseState *pstate, Node *merge, |
||||
List **mergeSourceTargetList) |
||||
{ |
||||
RangeTblEntry *rte, |
||||
*rt_rte; |
||||
List *namespace; |
||||
int rtindex, |
||||
rt_rtindex; |
||||
Node *n; |
||||
int mergeTarget_relation = list_length(pstate->p_rtable) + 1; |
||||
Var *var; |
||||
TargetEntry *te; |
||||
|
||||
n = transformFromClauseItem(pstate, merge, |
||||
&rte, |
||||
&rtindex, |
||||
&rt_rte, |
||||
&rt_rtindex, |
||||
&namespace); |
||||
|
||||
pstate->p_joinlist = list_make1(n); |
||||
|
||||
/*
|
||||
* We created an internal join between the target and the source relation |
||||
* to carry out the MERGE actions. Normally such an unaliased join hides |
||||
* the joining relations, unless the column references are qualified. |
||||
* Also, any unqualified column references are resolved to the Join RTE, if |
||||
* there is a matching entry in the targetlist. But the way MERGE |
||||
* execution is later setup, we expect all column references to resolve to |
||||
* either the source or the target relation. Hence we must not add the |
||||
* Join RTE to the namespace. |
||||
* |
||||
* The last entry must be for the top-level Join RTE. We don't want to |
||||
* resolve any references to the Join RTE. So discard that. |
||||
* |
||||
* We also do not want to resolve any references from the leftside of the |
||||
* Join since that corresponds to the target relation. References to the |
||||
* columns of the target relation must be resolved from the result |
||||
* relation and not the one that is used in the join. So the |
||||
* mergeTarget_relation is marked invisible to both qualified as well as |
||||
* unqualified references. |
||||
*/ |
||||
Assert(list_length(namespace) > 1); |
||||
namespace = list_truncate(namespace, list_length(namespace) - 1); |
||||
pstate->p_namespace = list_concat(pstate->p_namespace, namespace); |
||||
|
||||
setNamespaceVisibilityForRTE(pstate->p_namespace, |
||||
rt_fetch(mergeTarget_relation, pstate->p_rtable), false, false); |
||||
|
||||
/*
|
||||
* Expand the right relation and add its columns to the |
||||
* mergeSourceTargetList. Note that the right relation can either be a |
||||
* plain relation or a subquery or anything that can have a |
||||
* RangeTableEntry. |
||||
*/ |
||||
*mergeSourceTargetList = expandSourceTL(pstate, rt_rte, rt_rtindex); |
||||
|
||||
/*
|
||||
* Add a whole-row-Var entry to support references to "source.*". |
||||
*/ |
||||
var = makeWholeRowVar(rt_rte, rt_rtindex, 0, false); |
||||
te = makeTargetEntry((Expr *) var, list_length(*mergeSourceTargetList) + 1, |
||||
NULL, true); |
||||
*mergeSourceTargetList = lappend(*mergeSourceTargetList, te); |
||||
|
||||
return mergeTarget_relation; |
||||
} |
||||
|
||||
/*
|
||||
* 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 |
||||
setNamespaceForMergeAction(ParseState *pstate, MergeAction *action) |
||||
{ |
||||
RangeTblEntry *targetRelRTE, |
||||
*sourceRelRTE; |
||||
|
||||
/* Assume target relation is at index 1 */ |
||||
targetRelRTE = rt_fetch(1, pstate->p_rtable); |
||||
|
||||
/*
|
||||
* Assume that the top-level join RTE is at the end. The source relation |
||||
* is just before that. |
||||
*/ |
||||
sourceRelRTE = rt_fetch(list_length(pstate->p_rtable) - 1, pstate->p_rtable); |
||||
|
||||
switch (action->commandType) |
||||
{ |
||||
case CMD_INSERT: |
||||
|
||||
/*
|
||||
* Inserts can't see target relation, but they can see source |
||||
* relation. |
||||
*/ |
||||
setNamespaceVisibilityForRTE(pstate->p_namespace, |
||||
targetRelRTE, false, false); |
||||
setNamespaceVisibilityForRTE(pstate->p_namespace, |
||||
sourceRelRTE, true, true); |
||||
break; |
||||
|
||||
case CMD_UPDATE: |
||||
case CMD_DELETE: |
||||
|
||||
/*
|
||||
* Updates and deletes can see both target and source relations. |
||||
*/ |
||||
setNamespaceVisibilityForRTE(pstate->p_namespace, |
||||
targetRelRTE, true, true); |
||||
setNamespaceVisibilityForRTE(pstate->p_namespace, |
||||
sourceRelRTE, true, true); |
||||
break; |
||||
|
||||
case CMD_NOTHING: |
||||
break; |
||||
default: |
||||
elog(ERROR, "unknown action in MERGE WHEN clause"); |
||||
} |
||||
} |
||||
|
||||
/*
|
||||
* 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]; |
||||
JoinExpr *joinexpr; |
||||
RangeTblEntry *resultRelRTE, *mergeRelRTE; |
||||
|
||||
/* There can't be any outer WITH to worry about */ |
||||
Assert(pstate->p_ctenamespace == NIL); |
||||
|
||||
qry->commandType = CMD_MERGE; |
||||
|
||||
/*
|
||||
* Check WHEN clauses for permissions and sanity |
||||
*/ |
||||
is_terminal[0] = false; |
||||
is_terminal[1] = false; |
||||
foreach(l, stmt->mergeActionList) |
||||
{ |
||||
MergeAction *action = (MergeAction *) lfirst(l); |
||||
int when_type = (action->matched ? 0 : 1); |
||||
|
||||
/*
|
||||
* Collect action types so we can check Target permissions |
||||
*/ |
||||
switch (action->commandType) |
||||
{ |
||||
case CMD_INSERT: |
||||
{ |
||||
InsertStmt *istmt = (InsertStmt *) action->stmt; |
||||
SelectStmt *selectStmt = (SelectStmt *) istmt->selectStmt; |
||||
|
||||
/*
|
||||
* The grammar allows attaching ORDER BY, LIMIT, FOR |
||||
* UPDATE, or WITH to a VALUES clause and also multiple |
||||
* VALUES clauses. If we have any of those, ERROR. |
||||
*/ |
||||
if (selectStmt && (selectStmt->valuesLists == NIL || |
||||
selectStmt->sortClause != NIL || |
||||
selectStmt->limitOffset != NULL || |
||||
selectStmt->limitCount != NULL || |
||||
selectStmt->lockingClause != NIL || |
||||
selectStmt->withClause != NULL)) |
||||
ereport(ERROR, |
||||
(errcode(ERRCODE_SYNTAX_ERROR), |
||||
errmsg("SELECT not allowed in MERGE INSERT statement"))); |
||||
|
||||
if (selectStmt && list_length(selectStmt->valuesLists) > 1) |
||||
ereport(ERROR, |
||||
(errcode(ERRCODE_SYNTAX_ERROR), |
||||
errmsg("Multiple VALUES clauses not allowed in MERGE INSERT statement"))); |
||||
|
||||
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 (action->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"))); |
||||
} |
||||
|
||||
/*
|
||||
* Construct a query of the form |
||||
* SELECT relation.ctid --junk attribute |
||||
* ,relation.tableoid --junk attribute |
||||
* ,source_relation.<somecols> |
||||
* ,relation.<somecols> |
||||
* FROM relation RIGHT JOIN source_relation |
||||
* ON join_condition; -- no WHERE clause - all conditions are applied in |
||||
* executor |
||||
* |
||||
* stmt->relation is the target relation, given as a RangeVar |
||||
* stmt->source_relation is a RangeVar or subquery |
||||
* |
||||
* We specify the join as a RIGHT JOIN as a simple way of forcing the |
||||
* first (larg) RTE to refer to the target table. |
||||
* |
||||
* The MERGE query's join can be tuned in some cases, see below for these |
||||
* special case tweaks. |
||||
* |
||||
* We set QSRC_PARSER to show query constructed in parse analysis |
||||
* |
||||
* Note that we have only one Query for a MERGE statement and the planner |
||||
* is called only once. That query is executed once to produce our stream |
||||
* of candidate change rows, so the query must contain all of the columns |
||||
* required by each of the targetlist or conditions for each action. |
||||
* |
||||
* As top-level statements INSERT, UPDATE and DELETE have a Query, whereas |
||||
* with MERGE the individual actions do not require separate planning, |
||||
* only different handling in the executor. See nodeModifyTable handling |
||||
* of commandType CMD_MERGE. |
||||
* |
||||
* A sub-query can include the Target, but otherwise the sub-query cannot |
||||
* reference the outermost Target table at all. |
||||
*/ |
||||
qry->querySource = QSRC_PARSER; |
||||
|
||||
/*
|
||||
* Setup the target table. Unlike regular UPDATE/DELETE, we don't expand |
||||
* inheritance for the target relation in case of MERGE. |
||||
* |
||||
* This special arrangement is required for handling partitioned tables |
||||
* because we perform an JOIN between the target and the source relation to |
||||
* identify the matching and not-matching rows. If we take the usual path |
||||
* of expanding the target table's inheritance and create one subplan per |
||||
* partition, then we we won't be able to correctly identify the matching |
||||
* and not-matching rows since for a given source row, there may not be a |
||||
* matching row in one partition, but it may exists in some other |
||||
* partition. So we must first append all the qualifying rows from all the |
||||
* partitions and then do the matching. |
||||
* |
||||
* Once a target row is returned by the underlying join, we find the |
||||
* correct partition and setup required state to carry out UPDATE/DELETE. |
||||
* All of this happens during execution. |
||||
*/ |
||||
qry->resultRelation = setTargetTable(pstate, stmt->relation, |
||||
false, /* do not expand inheritance */ |
||||
true, targetPerms); |
||||
|
||||
/*
|
||||
* Create a JOIN between the target and the source relation. |
||||
*/ |
||||
joinexpr = makeNode(JoinExpr); |
||||
joinexpr->isNatural = false; |
||||
joinexpr->alias = NULL; |
||||
joinexpr->usingClause = NIL; |
||||
joinexpr->quals = stmt->join_condition; |
||||
joinexpr->larg = (Node *) stmt->relation; |
||||
joinexpr->rarg = (Node *) stmt->source_relation; |
||||
|
||||
/*
|
||||
* Simplify the MERGE query as much as possible |
||||
* |
||||
* These seem like things that could go into Optimizer, but they are |
||||
* semantic simplifications rather than optimizations, per se. |
||||
* |
||||
* If there are no INSERT actions we won't be using the non-matching |
||||
* candidate rows for anything, so no need for an outer join. We do still |
||||
* need an inner join for UPDATE and DELETE actions. |
||||
*/ |
||||
if (targetPerms & ACL_INSERT) |
||||
joinexpr->jointype = JOIN_RIGHT; |
||||
else |
||||
joinexpr->jointype = JOIN_INNER; |
||||
|
||||
/*
|
||||
* We use a special purpose transformation here because the normal |
||||
* routines don't quite work right for the MERGE case. |
||||
* |
||||
* A special mergeSourceTargetList is setup by transformMergeJoinClause(). |
||||
* It refers to all the attributes provided by the source relation. This |
||||
* is later used by set_plan_refs() to fix the UPDATE/INSERT target lists |
||||
* to so that they can correctly fetch the attributes from the source |
||||
* relation. |
||||
* |
||||
* The target relation when used in the underlying join, gets a new RTE |
||||
* with rte->inh set to true. We remember this RTE (and later pass on to |
||||
* the planner and executor) for two main reasons: |
||||
* |
||||
* 1. If we ever need to run EvalPlanQual while performing MERGE, we must |
||||
* make the modified tuple available to the underlying join query, which is |
||||
* using a different RTE from the resultRelation RTE. |
||||
* |
||||
* 2. rewriteTargetListMerge() requires the RTE of the underlying join in |
||||
* order to add junk CTID and TABLEOID attributes. |
||||
*/ |
||||
qry->mergeTarget_relation = transformMergeJoinClause(pstate, (Node *) joinexpr, |
||||
&qry->mergeSourceTargetList); |
||||
|
||||
/*
|
||||
* The target table referenced in the MERGE is looked up twice; once while |
||||
* setting it up as the result relation and again when it's used in the |
||||
* underlying the join query. In some rare situations, it may happen that |
||||
* these lookups return different results, for example, if a new relation |
||||
* with the same name gets created in a schema which is ahead in the |
||||
* search_path, in between the two lookups. |
||||
* |
||||
* It's a very narrow case, but nevertheless we guard against it by simply |
||||
* checking if the OIDs returned by the two lookups is the same. If not, we |
||||
* just throw an error. |
||||
*/ |
||||
Assert(qry->resultRelation > 0); |
||||
Assert(qry->mergeTarget_relation > 0); |
||||
|
||||
/* Fetch both the RTEs */ |
||||
resultRelRTE = rt_fetch(qry->resultRelation, pstate->p_rtable); |
||||
mergeRelRTE = rt_fetch(qry->mergeTarget_relation, pstate->p_rtable); |
||||
|
||||
if (resultRelRTE->relid != mergeRelRTE->relid) |
||||
ereport(ERROR, |
||||
(errcode(ERRCODE_OBJECT_NOT_IN_PREREQUISITE_STATE), |
||||
errmsg("relation referenced by MERGE statement has changed"))); |
||||
|
||||
/*
|
||||
* This query should just provide the source relation columns. Later, in |
||||
* preprocess_targetlist(), we shall also add "ctid" attribute of the |
||||
* target relation to ensure that the target tuple can be fetched |
||||
* correctly. |
||||
*/ |
||||
qry->targetList = qry->mergeSourceTargetList; |
||||
|
||||
/* qry has no WHERE clause so absent quals are shown as NULL */ |
||||
qry->jointree = makeFromExpr(pstate->p_joinlist, NULL); |
||||
qry->rtable = pstate->p_rtable; |
||||
|
||||
/*
|
||||
* XXX 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("MERGE is not supported for this relation type"))); |
||||
|
||||
if (pstate->p_target_relation->rd_rel->relkind != RELKIND_PARTITIONED_TABLE && |
||||
pstate->p_target_relation->rd_rel->relhassubclass) |
||||
ereport(ERROR, |
||||
(errcode(ERRCODE_FEATURE_NOT_SUPPORTED), |
||||
errmsg("MERGE is not supported for relations with inheritance"))); |
||||
|
||||
if (pstate->p_target_relation->rd_rel->relhasrules) |
||||
ereport(ERROR, |
||||
(errcode(ERRCODE_FEATURE_NOT_SUPPORTED), |
||||
errmsg("MERGE is not supported for relations with rules"))); |
||||
|
||||
/*
|
||||
* 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. |
||||
*/ |
||||
foreach(l, stmt->mergeActionList) |
||||
{ |
||||
MergeAction *action = (MergeAction *) lfirst(l); |
||||
|
||||
/*
|
||||
* Set namespace for the specific action. This must be done before |
||||
* analyzing the WHEN quals and the action targetlisst. |
||||
*/ |
||||
setNamespaceForMergeAction(pstate, action); |
||||
|
||||
/*
|
||||
* 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, action->condition, |
||||
EXPR_KIND_MERGE_WHEN_AND, "WHEN"); |
||||
|
||||
/*
|
||||
* Transform target lists for each INSERT and UPDATE action stmt |
||||
*/ |
||||
switch (action->commandType) |
||||
{ |
||||
case CMD_INSERT: |
||||
{ |
||||
InsertStmt *istmt = (InsertStmt *) action->stmt; |
||||
SelectStmt *selectStmt = (SelectStmt *) istmt->selectStmt; |
||||
List *exprList = NIL; |
||||
ListCell *lc; |
||||
RangeTblEntry *rte; |
||||
ListCell *icols; |
||||
ListCell *attnos; |
||||
List *icolumns; |
||||
List *attrnos; |
||||
|
||||
pstate->p_is_insert = true; |
||||
|
||||
icolumns = checkInsertTargets(pstate, istmt->cols, &attrnos); |
||||
Assert(list_length(icolumns) == list_length(attrnos)); |
||||
|
||||
/*
|
||||
* Handle INSERT much like in transformInsertStmt |
||||
*/ |
||||
if (selectStmt == NULL) |
||||
{ |
||||
/*
|
||||
* 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. |
||||
*/ |
||||
List *valuesLists = selectStmt->valuesLists; |
||||
|
||||
Assert(list_length(valuesLists) == 1); |
||||
Assert(selectStmt->intoClause == NULL); |
||||
|
||||
/*
|
||||
* Do basic expression transformation (same as a ROW() |
||||
* expr, but allow SetToDefault at top level) |
||||
*/ |
||||
exprList = transformExpressionList(pstate, |
||||
(List *) linitial(valuesLists), |
||||
EXPR_KIND_VALUES_SINGLE, |
||||
true); |
||||
|
||||
/* Prepare row for assignment to target table */ |
||||
exprList = transformInsertRow(pstate, exprList, |
||||
istmt->cols, |
||||
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_rangetblentry; |
||||
icols = list_head(icolumns); |
||||
attnos = list_head(attrnos); |
||||
foreach(lc, exprList) |
||||
{ |
||||
Expr *expr = (Expr *) lfirst(lc); |
||||
ResTarget *col; |
||||
AttrNumber attr_num; |
||||
TargetEntry *tle; |
||||
|
||||
col = lfirst_node(ResTarget, icols); |
||||
attr_num = (AttrNumber) lfirst_int(attnos); |
||||
|
||||
tle = makeTargetEntry(expr, |
||||
attr_num, |
||||
col->name, |
||||
false); |
||||
action->targetList = lappend(action->targetList, tle); |
||||
|
||||
rte->insertedCols = bms_add_member(rte->insertedCols, |
||||
attr_num - FirstLowInvalidHeapAttributeNumber); |
||||
|
||||
icols = lnext(icols); |
||||
attnos = lnext(attnos); |
||||
} |
||||
} |
||||
break; |
||||
case CMD_UPDATE: |
||||
{ |
||||
UpdateStmt *ustmt = (UpdateStmt *) action->stmt; |
||||
|
||||
pstate->p_is_insert = false; |
||||
action->targetList = transformUpdateTargetList(pstate, ustmt->targetList); |
||||
} |
||||
break; |
||||
case CMD_DELETE: |
||||
break; |
||||
|
||||
case CMD_NOTHING: |
||||
action->targetList = NIL; |
||||
break; |
||||
default: |
||||
elog(ERROR, "unknown action in MERGE WHEN clause"); |
||||
} |
||||
} |
||||
|
||||
qry->mergeActionList = stmt->mergeActionList; |
||||
|
||||
/* XXX maybe later */ |
||||
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; |
||||
} |
||||
} |
||||
|
||||
} |
||||
|
||||
/*
|
||||
* Expand the source relation to include all attributes of this RTE. |
||||
* |
||||
* This function is very similar to expandRelAttrs except that we don't mark |
||||
* columns for SELECT privileges. That will be decided later when we transform |
||||
* the action targetlists and the WHEN quals for actual references to the |
||||
* source relation. |
||||
*/ |
||||
static List * |
||||
expandSourceTL(ParseState *pstate, RangeTblEntry *rte, int rtindex) |
||||
{ |
||||
List *names, |
||||
*vars; |
||||
ListCell *name, |
||||
*var; |
||||
List *te_list = NIL; |
||||
|
||||
expandRTE(rte, rtindex, 0, -1, false, &names, &vars); |
||||
|
||||
/*
|
||||
* Require read access to the table. |
||||
*/ |
||||
rte->requiredPerms |= ACL_SELECT; |
||||
|
||||
forboth(name, names, var, vars) |
||||
{ |
||||
char *label = strVal(lfirst(name)); |
||||
Var *varnode = (Var *) lfirst(var); |
||||
TargetEntry *te; |
||||
|
||||
te = makeTargetEntry((Expr *) varnode, |
||||
(AttrNumber) pstate->p_next_resno++, |
||||
label, |
||||
false); |
||||
te_list = lappend(te_list, te); |
||||
} |
||||
|
||||
Assert(name == NULL && var == NULL); /* lists not the same length? */ |
||||
|
||||
return te_list; |
||||
} |
@ -0,0 +1,22 @@ |
||||
/*-------------------------------------------------------------------------
|
||||
* |
||||
* nodeMerge.h |
||||
* |
||||
* |
||||
* Portions Copyright (c) 1996-2018, PostgreSQL Global Development Group |
||||
* Portions Copyright (c) 1994, Regents of the University of California |
||||
* |
||||
* src/include/executor/nodeMerge.h |
||||
* |
||||
*------------------------------------------------------------------------- |
||||
*/ |
||||
#ifndef NODEMERGE_H |
||||
#define NODEMERGE_H |
||||
|
||||
#include "nodes/execnodes.h" |
||||
|
||||
extern void |
||||
ExecMerge(ModifyTableState *mtstate, EState *estate, TupleTableSlot *slot, |
||||
JunkFilter *junkfilter, ResultRelInfo *resultRelInfo); |
||||
|
||||
#endif /* NODEMERGE_H */ |
@ -0,0 +1,19 @@ |
||||
/*-------------------------------------------------------------------------
|
||||
* |
||||
* parse_merge.h |
||||
* handle merge-stmt in parser |
||||
* |
||||
* |
||||
* Portions Copyright (c) 1996-2018, 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 |
@ -0,0 +1,97 @@ |
||||
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 |
||||
|
||||
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 |
||||
|
||||
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 |
||||
|
||||
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 |
||||
|
||||
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 |
||||
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 |
||||
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 |
||||
|
||||
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 |
||||
|
||||
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 |
||||
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 |
||||
step c2: COMMIT; |
@ -0,0 +1,84 @@ |
||||
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 |
||||
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 |
||||
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 in steps c1 merge2: 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 in steps c1 merge2: 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 |
||||
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 |
||||
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 in steps c1 merge2: 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 |
||||
step c2: COMMIT; |
@ -0,0 +1,106 @@ |
||||
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 |
||||
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 |
||||
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 |
||||
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 |
||||
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 |
||||
step c1: COMMIT; |
@ -0,0 +1,213 @@ |
||||
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 |
||||
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 |
||||
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 |
||||
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 |
||||
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 |
||||
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 |
||||
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_merge2a |
||||
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_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_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 |
||||
|
||||
1 pa_merge2a |
||||
2 initial |
||||
2 initial updated by pa_merge1 |
||||
step c2: COMMIT; |
@ -0,0 +1,51 @@ |
||||
# 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; } |
||||
step "a1" { ABORT; } |
||||
|
||||
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,52 @@ |
||||
# 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; } |
||||
step "a2" { ABORT; } |
||||
|
||||
# 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,79 @@ |
||||
# 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; } |
||||
step "a1" { ABORT; } |
||||
|
||||
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 "select2" { SELECT * FROM target; } |
||||
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,132 @@ |
||||
# MERGE UPDATE |
||||
# |
||||
# This test exercises atypical cases |
||||
# 1. UPDATEs of PKs that change the join in the ON clause |
||||
# 2. UPDATEs with WHEN AND 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_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 "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; |
||||
} |
||||
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" |
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