APP_JUMB(query->specClause);
JumbleExpr(jstate, (Node *) query->arbiterElems);
JumbleExpr(jstate, query->arbiterWhere);
+ if (query->onConflict)
+ JumbleQuery(jstate, (Query *) query->onConflict);
JumbleExpr(jstate, (Node *) query->returningList);
JumbleExpr(jstate, (Node *) query->groupClause);
JumbleExpr(jstate, query->havingQual);
INSERT INTO ft1(c1, c2) VALUES(11, 12) ON CONFLICT IGNORE; -- works
INSERT INTO ft1(c1, c2) VALUES(11, 12) ON CONFLICT (c1, c2) IGNORE; -- unsupported
ERROR: postgres_fdw does not support ON CONFLICT unique index inference
+INSERT INTO ft1(c1, c2) VALUES(11, 12) ON CONFLICT (c1, c2) UPDATE SET c3 = 'ffg'; -- unsupported
+ERROR: postgres_fdw does not support ON CONFLICT unique index inference
INSERT INTO ft1(c1, c2) VALUES(1111, -2); -- c2positive
ERROR: new row for relation "T 1" violates check constraint "c2positive"
DETAIL: Failing row contains (1111, -2, null, null, null, null, ft1 , null).
errmsg("postgres_fdw does not support ON CONFLICT unique index inference")));
else if (plan->spec == SPEC_IGNORE)
ignore = true;
+ /*
+ * SPEC_INSERT case should be rejected in the optimizer, as presently there
+ * is no basis to recognize an arbiter unique index on a foreign table
+ */
else if (plan->spec != SPEC_NONE)
elog(ERROR, "unexpected speculative specification: %d", (int) plan->spec);
INSERT INTO ft1(c1, c2) VALUES(11, 12); -- duplicate key
INSERT INTO ft1(c1, c2) VALUES(11, 12) ON CONFLICT IGNORE; -- works
INSERT INTO ft1(c1, c2) VALUES(11, 12) ON CONFLICT (c1, c2) IGNORE; -- unsupported
+INSERT INTO ft1(c1, c2) VALUES(11, 12) ON CONFLICT (c1, c2) UPDATE SET c3 = 'ffg'; -- unsupported
INSERT INTO ft1(c1, c2) VALUES(1111, -2); -- c2positive
UPDATE ft1 SET c2 = -c2 WHERE c1 = 1; -- c2positive
COMMIT
(9 rows)
+-- ON CONFLICT UPDATE support
+BEGIN;
+INSERT INTO replication_example(id, somedata, somenum) SELECT i, i, i FROM generate_series(-15, 15) i
+ ON CONFLICT (id) UPDATE SET somenum = excluded.somenum + 1;
+COMMIT;
+/* display results, but hide most of the output */
+SELECT count(*), min(data), max(data)
+FROM pg_logical_slot_get_changes('regression_slot', NULL, NULL, 'include-xids', '0', 'skip-empty-xacts', '1')
+GROUP BY substring(data, 1, 40)
+ORDER BY 1,2;
+ count | min | max
+-------+----------------------------------------------------------------------------------------------------------------------------------------------+-----------------------------------------------------------------------------------------------------------------------------------------------
+ 1 | BEGIN | BEGIN
+ 1 | COMMIT | COMMIT
+ 15 | table public.replication_example: UPDATE: id[integer]:10 somedata[integer]:4 somenum[integer]:11 zaphod1[integer]:null zaphod2[integer]:null | table public.replication_example: UPDATE: id[integer]:9 somedata[integer]:3 somenum[integer]:10 zaphod1[integer]:null zaphod2[integer]:null
+ 16 | table public.replication_example: INSERT: id[integer]:0 somedata[integer]:0 somenum[integer]:0 zaphod1[integer]:null zaphod2[integer]:null | table public.replication_example: INSERT: id[integer]:-9 somedata[integer]:-9 somenum[integer]:-9 zaphod1[integer]:null zaphod2[integer]:null
+(4 rows)
+
-- hide changes bc of oid visible in full table rewrites
CREATE TABLE tr_unique(id2 serial unique NOT NULL, data int);
INSERT INTO tr_unique(data) VALUES(10);
-- show changes
SELECT data FROM pg_logical_slot_get_changes('regression_slot', NULL, NULL, 'include-xids', '0', 'skip-empty-xacts', '1');
+-- ON CONFLICT UPDATE support
+BEGIN;
+INSERT INTO replication_example(id, somedata, somenum) SELECT i, i, i FROM generate_series(-15, 15) i
+ ON CONFLICT (id) UPDATE SET somenum = excluded.somenum + 1;
+COMMIT;
+
+/* display results, but hide most of the output */
+SELECT count(*), min(data), max(data)
+FROM pg_logical_slot_get_changes('regression_slot', NULL, NULL, 'include-xids', '0', 'skip-empty-xacts', '1')
+GROUP BY substring(data, 1, 40)
+ORDER BY 1,2;
+
-- hide changes bc of oid visible in full table rewrites
CREATE TABLE tr_unique(id2 serial unique NOT NULL, data int);
INSERT INTO tr_unique(data) VALUES(10);
not <literal>INSERT</literal> or <literal>ALTER TABLE ...
RENAME</literal>) typically default to including child tables and
support the <literal>ONLY</literal> notation to exclude them.
+ <literal>INSERT</literal> with an <literal>ON CONFLICT
+ UPDATE</literal> clause does not support the
+ <literal>ONLY</literal> notation (it is not a special case).
Commands that do database maintenance and tuning
(e.g., <literal>REINDEX</literal>, <literal>VACUUM</literal>)
typically only work on individual, physical tables and do not
<command>INSERT</> with an <literal>ON CONFLICT</> clause is not
supported with a unique index inference specification, since a
conflict arbitrating unique index cannot meaningfully be inferred
- on a foreign table.
+ on a foreign table (this implies that <literal>ON CONFLICT
+ UPDATE</> is never supported, since the specification is
+ mandatory there).
</para>
</sect1>
locked and returned to the client.
</para>
+ <para>
+ <command>INSERT</command> with an <literal>ON CONFLICT UPDATE</> clause is
+ another special case. In Read Committed mode, the implementation will
+ either insert or update each row proposed for insertion, with either one of
+ those two outcomes guaranteed. This is a useful guarantee for many
+ use-cases, but it implies that further liberties must be taken with
+ snapshot isolation. Should a conflict originate in another transaction
+ whose effects are not visible to the <command>INSERT</command>, the
+ <command>UPDATE</command> may affect that row, even though it may be the
+ case that <emphasis>no</> version of that row is conventionally visible to
+ the command. In the same vein, if the secondary search condition of the
+ command (an explicit <literal>WHERE</> clause) is supplied, it is only
+ evaluated on the most recent row version, which is not necessarily the
+ version conventionally visible to the command (if indeed there is a row
+ version conventionally visible to the command at all).
+ </para>
+
+ <para>
+ <command>INSERT</command> with an <literal>ON CONFLICT IGNORE</> clause may
+ have insertion not proceed for a row due to the outcome of another
+ transaction whose effects are not visible to the <command>INSERT</command>
+ snapshot. Again, this is only the case in Read Committed mode.
+ </para>
+
<para>
Because of the above rule, it is possible for an updating command to see an
inconsistent snapshot: it can see the effects of concurrent updating
<para>
This example uses exception handling to perform either
- <command>UPDATE</> or <command>INSERT</>, as appropriate:
+ <command>UPDATE</> or <command>INSERT</>, as appropriate. It is
+ recommended that applications use <command>INSERT</> with
+ <literal>ON CONFLICT UPDATE</> rather than actually emulating this
+ pattern. This example serves only to illustrate use of
+ <application>PL/pgSQL</application> control flow structures:
<programlisting>
CREATE TABLE db (a INT PRIMARY KEY, b TEXT);
<command>INSERT</> and <command>UPDATE</> operations, the return value
should be <varname>NEW</>, which the trigger function may modify to
support <command>INSERT RETURNING</> and <command>UPDATE RETURNING</>
- (this will also affect the row value passed to any subsequent triggers).
- For <command>DELETE</> operations, the return value should be
- <varname>OLD</>.
+ (this will also affect the row value passed to any subsequent triggers,
+ or passed to a special <varname>EXCLUDED</> alias reference within
+ an <command>INSERT</> statement with an <literal>ON CONFLICT UPDATE</>
+ clause). For <command>DELETE</> operations, the return
+ value should be <varname>OLD</>.
</para>
<para>
</para>
<para>
- <filename>postgres_fdw</> supports <command>INSERT</command>
- statements with an <literal>ON CONFLICT IGNORE</> clause, provided a
- unique index inference specification is omitted.
+ Note that <filename>postgres_fdw</> currently lacks support for
+ <command>INSERT</command> statements with an <literal>ON CONFLICT
+ UPDATE</> clause. However, the <literal>ON CONFLICT IGNORE</>
+ clause is supported, provided a unique index inference specification
+ is omitted.
</para>
<para>
<literal>INSERT <replaceable>oid</replaceable>
<replaceable>rows</replaceable></literal>, where
<replaceable>rows</replaceable> is the number of rows
- inserted. <replaceable>oid</replaceable> is the object ID
- of the inserted row if <replaceable>rows</replaceable> is 1
- and the target table has OIDs;
+ inserted. However, if and only if <literal>ON CONFLICT
+ UPDATE</> is specified, then the tag is <literal>UPSERT
+ <replaceable>oid</replaceable>
+ <replaceable>rows</replaceable></literal>, where
+ <replaceable>rows</replaceable> is the number of rows inserted
+ <emphasis>or updated</emphasis>.
+ <replaceable>oid</replaceable> is the object ID of the
+ inserted row if <replaceable>rows</replaceable> is 1 and the
+ target table has OIDs, and (for the <literal>UPSERT</literal>
+ tag), the row was actually inserted rather than updated;
otherwise <replaceable>oid</replaceable> is 0.
</para>
The event is one of <literal>SELECT</literal>,
<literal>INSERT</literal>, <literal>UPDATE</literal>, or
<literal>DELETE</literal>. Note that an
- <command>INSERT</command> containing an <literal>ON CONFLICT
- IGNORE</literal> clause cannot be used on tables that have
+ <command>INSERT</command> containing an <literal>ON
+ CONFLICT</literal> clause cannot be used on tables that have
either <literal>INSERT</literal> or <literal>UPDATE</literal>
rules. Consider using an updatable view instead, which are
- supported with <literal>ON CONFLICT IGNORE</literal>.
+ supported with <literal>ON CONFLICT IGNORE</literal> only.
</para>
</listitem>
</varlistentry>
deferrable. Note that constraints that were created with this
clause cannot be used as arbiters of whether or not to take the
alternative path with an <command>INSERT</command> statement
- that includes an <literal>ON CONFLICT</> clause.
+ that includes an <literal>ON CONFLICT UPDATE</> clause.
</para>
</listitem>
</varlistentry>
executes once for any given operation, regardless of how many rows
it modifies (in particular, an operation that modifies zero rows
will still result in the execution of any applicable <literal>FOR
- EACH STATEMENT</literal> triggers).
+ EACH STATEMENT</literal> triggers). Note that with an
+ <command>INSERT</command> with an <literal>ON CONFLICT UPDATE</>
+ clause, both <command>INSERT</command> and
+ <command>UPDATE</command> statement level trigger will be fired.
</para>
<para>
<para>
Simple views are automatically updatable: the system will allow
- <command>INSERT</>, <command>UPDATE</> and <command>DELETE</> statements
- to be used on the view in the same way as on a regular table (aside from
- the limitations on ON CONFLICT noted below). A view is automatically
- updatable if it satisfies all of the following conditions:
+ <command>INSERT</>, <command>UPDATE</> and <command>DELETE</>
+ statements to be used on the view in the same way as on a regular
+ table (although <literal>ON CONFLICT UPDATE</> is not supported).
+ A view is automatically updatable if it satisfies all of the
+ following conditions:
<itemizedlist>
<listitem>
<command>INSERT</command> with an <literal>ON CONFLICT IGNORE</>
clause is supported on updatable views (if an inference
specification is provided, it must infer a unique index on the
- underlying base relation).
+ underlying base relation). <literal>ON CONFLICT UPDATE</> is not
+ supported on updatable views, however.
</para>
</refsect2>
</refsect1>
[ WITH [ RECURSIVE ] <replaceable class="parameter">with_query</replaceable> [, ...] ]
INSERT INTO <replaceable class="PARAMETER">table_name</replaceable> [ ( <replaceable class="PARAMETER">column_name</replaceable> [, ...] ) ]
{ DEFAULT VALUES | VALUES ( { <replaceable class="PARAMETER">expression</replaceable> | DEFAULT } [, ...] ) [, ...] | <replaceable class="PARAMETER">query</replaceable> }
- [ ON CONFLICT [ ( { <replaceable class="parameter">column_name_index</replaceable> | ( <replaceable class="parameter">expression_index</replaceable> ) } [ COLLATE <replaceable class="parameter">collation</replaceable> ] [ <replaceable class="parameter">opclass</replaceable> ] [, ...] [ WHERE <replaceable class="PARAMETER">index_predicate</replaceable> ] ) ] IGNORE]
+ [ ON CONFLICT [ ( { <replaceable class="parameter">column_name_index</replaceable> | ( <replaceable class="parameter">expression_index</replaceable> ) } [ COLLATE <replaceable class="parameter">collation</replaceable> ] [ <replaceable class="parameter">opclass</replaceable> ] [, ...] [ WHERE <replaceable class="PARAMETER">index_predicate</replaceable> ] ) ]
+ { IGNORE | 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 } [, ...] )
+ } [, ...]
+ [ WHERE <replaceable class="PARAMETER">condition</replaceable> ]
+ }
+ ]
[ RETURNING * | <replaceable class="parameter">output_expression</replaceable> [ [ AS ] <replaceable class="parameter">output_name</replaceable> ] [, ...] ]
</synopsis>
</refsynopsisdiv>
</para>
<para>
+ <indexterm zone="SQL-INSERT">
+ <primary>UPSERT</primary>
+ </indexterm>
The optional <literal>ON CONFLICT</> clause specifies a path to
take as an alternative to raising a conflict related error. The
alternative path is considered individually for each row proposed
for insertion; it is taken (or not taken) once per row.
<literal>ON CONFLICT IGNORE</> simply avoids inserting any
individual row when it is determined that a conflict related error
- would otherwise need to be raised.
+ would otherwise need to be raised. <literal>ON CONFLICT UPDATE</>
+ has the system take an <command>UPDATE</command> path in respect of
+ such rows instead. <literal>ON CONFLICT UPDATE</> guarantees an
+ atomic <command>INSERT</command> or <command>UPDATE</command>
+ outcome - provided there is no incidental error, one of those two
+ outcomes is guaranteed, even under high concurrency. This feature
+ is also known as <firstterm>UPSERT</firstterm>.
</para>
<para>
associated with an index where that isn't explicitly anticipated.
</para>
+ <para>
+ <literal>ON CONFLICT UPDATE</> makes a unique index inference
+ specification mandatory, since taking the alternative
+ <command>UPDATE</command> path can only reasonably occur due to an
+ <emphasis>anticipated</emphasis> conflict. <literal>ON CONFLICT
+ UPDATE</> optionally accepts a <literal>WHERE</> clause
+ <replaceable>condition</>. When provided, the statement only
+ proceeds with updating if the <replaceable>condition</> is
+ satisfied. Otherwise, unlike a conventional
+ <command>UPDATE</command>, the row is still locked for update.
+ Note that the <replaceable>condition</> is evaluated last, after a
+ conflict has been identified as a candidate to update.
+ </para>
+
+ <para>
+ <literal>ON CONFLICT UPDATE</> is effectively an auxiliary query of
+ its parent <command>INSERT</command>. Two special aliases are
+ visible when <literal>ON CONFLICT UPDATE</> is specified -
+ <varname>TARGET</> and <varname>EXCLUDED</>. The first alias is a
+ standard, generic alias for the target relation used when an
+ <literal>ON CONFLICT UPDATE</> clause appears, while the second
+ alias refers to rows originally proposed for insertion, but found
+ to make the implementation take the alternative
+ <command>UPDATE</command> path. Both aliases can be used in the
+ auxiliary <command>UPDATE</command> <literal>SET</> assignment list
+ within any expression assigning to a <replaceable
+ class="PARAMETER">column_name</replaceable>, and both can be used
+ in the auxiliary <command>UPDATE</command> <literal>WHERE</> clause
+ <replaceable class="PARAMETER">condition</replaceable>. However,
+ the <varname>TARGET</> alias can be used anywhere where the target
+ is visible within the entire statement. The <varname>EXCLUDED</>
+ alias allows <literal>SET</> assignments to reference rows proposed
+ for but excluded from insertion. This is particularly useful for
+ multiple row statements; when inserting or updating multiple rows,
+ constants or parameter values need only appear once. Note that the
+ effects of all per-row <literal>BEFORE INSERT</> triggers are
+ reflected in <varname>EXCLUDED</> values, since those effects may
+ have contributed to the row being excluded from insertion.
+ </para>
+
+ <para>
+ There are several restrictions on the <literal>ON CONFLICT
+ UPDATE</> clause that do not apply to <command>UPDATE</command>
+ statements. Subqueries may not appear in either the
+ <command>UPDATE</command> targetlist, nor its <literal>WHERE</>
+ clause <replaceable>condition</> (although simple multi-assignment
+ expressions are supported). <literal>WHERE CURRENT OF</> cannot be
+ used. Only columns from the <varname>TARGET</> and
+ <varname>EXCLUDED</> rows may be referenced. Operators and
+ functions may be used freely, though.
+ </para>
+
+ <para>
+ <command>INSERT</command> with an <literal>ON CONFLICT UPDATE</>
+ clause is a <quote>deterministic</quote> statement. This means
+ that the command will not be allowed to affect any single existing
+ row more than once; a cardinality violation error will be raised
+ when this situation arises. Rows proposed for insertion should not
+ duplicate each other in terms of attributes constrained by the
+ conflict-arbitrating unique index. Note that the ordinary rules
+ for unique indexes with regard to null apply analogously to whether
+ or not an arbitrating unique index indicates if the alternative
+ path should be taken. This means that when a null value appears in
+ any uniquely constrained tuple's attribute in an
+ <command>INSERT</command> statement with <literal>ON CONFLICT
+ UPDATE</literal>, rows proposed for insertion will never take the
+ alternative path (provided that a <literal>BEFORE ROW
+ INSERT</literal> trigger does not make null values non-null before
+ insertion); the statement will always insert, assuming there is no
+ unrelated error. Note that merely locking a row (by having it not
+ satisfy the <literal>WHERE</> clause <replaceable>condition</>)
+ does not count towards whether or not the row has been affected
+ multiple times (and whether or not a cardinality violation error is
+ raised). However, the implementation checks for cardinality
+ violations after locking the row, and before updating (or
+ considering updating), so a cardinality violation may be raised
+ despite the fact that the row would not otherwise have gone on to
+ be updated.
+ </para>
+
<para>
Columns and/or expressions appearing in a unique index inference
specification must match all the columns/expressions of some
<para>
The optional <literal>RETURNING</> clause causes <command>INSERT</>
- to compute and return value(s) based on each row actually inserted.
+ to compute and return value(s) based on each row actually inserted
+ (or updated, if an <literal>ON CONFLICT UPDATE</> clause was used).
This is primarily useful for obtaining values that were supplied by
defaults, such as a serial sequence number. However, any expression
using the table's columns is allowed. The syntax of the
<literal>RETURNING</> list is identical to that of the output list
- of <command>SELECT</>.
+ of <command>SELECT</>. Only rows that were successfully inserted
+ or updated will be returned. If a row was locked but not updated
+ because an <literal>ON CONFLICT UPDATE</> <literal>WHERE</> clause
+ did not pass, the row will not be returned. Since
+ <literal>RETURNING</> is not part of the auxiliary
+ <command>UPDATE</> query, the special <literal>ON CONFLICT
+ UPDATE</> <varname>EXCLUDED</> alias may not be referenced; only
+ the row as it exists after updating (or inserting) is returned.
+ However, <literal>RETURNING</> may qualify returned rows using the
+ <varname>TARGET</> alias.
</para>
<para>
You must have <literal>INSERT</literal> privilege on a table in
- order to insert into it. If a column list is specified, you only
- need <literal>INSERT</literal> privilege on the listed columns.
- Use of the <literal>RETURNING</> clause requires <literal>SELECT</>
- privilege on all columns mentioned in <literal>RETURNING</>.
- If you use the <replaceable
- class="PARAMETER">query</replaceable> clause to insert rows from a
- query, you of course need to have <literal>SELECT</literal> privilege on
- any table or column used in the query.
+ order to insert into it, as well as <literal>UPDATE
+ privilege</literal> if and only if <literal>ON CONFLICT UPDATE</>
+ is specified. If a column list is specified, you only need
+ <literal>INSERT</literal> privilege on the listed columns.
+ Similarly, when <literal>ON CONFLICT UPDATE</> is specified, you
+ only need <literal>UPDATE</> privilege on the column(s) that are
+ listed to be updated, as well as SELECT privilege on any column
+ whose values are read in the <literal>ON CONFLICT UPDATE</>
+ expressions or <replaceable>condition</>. Use of the
+ <literal>RETURNING</> clause requires <literal>SELECT</> privilege
+ on all columns mentioned in <literal>RETURNING</>. If you use the
+ <replaceable class="PARAMETER">query</replaceable> clause to insert
+ rows from a query, you of course need to have
+ <literal>SELECT</literal> privilege on any table or column used in
+ the query.
</para>
</refsect1>
The name of a column in the table named by <replaceable class="PARAMETER">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.)
+ composite column leaves the other fields null.) When
+ referencing a column with <literal>ON CONFLICT UPDATE</>, do not
+ include the table's name in the specification of a target
+ column. For example, <literal>INSERT ... ON CONFLICT UPDATE tab
+ SET TARGET.col = 1</> is invalid (this follows the general
+ behavior for <command>UPDATE</>).
</para>
</listitem>
</varlistentry>
</varlistentry>
<varlistentry>
+ <term><replaceable class="PARAMETER">condition</replaceable></term>
+ <listitem>
+ <para>
+ An expression that returns a value of type <type>boolean</type>.
+ Only rows for which this expression returns <literal>true</>
+ will be updated, although all rows will be locked when the
+ <literal>ON CONFLICT UPDATE</> path is taken.
+ </para>
+ </listitem>
+ </varlistentry>
+ <varlistentry>
+
<term><replaceable class="PARAMETER">output_expression</replaceable></term>
<listitem>
<para>
tag of the form
<screen>
INSERT <replaceable>oid</replaceable> <replaceable class="parameter">count</replaceable>
+</screen>
+ However, in the event of an <literal>ON CONFLICT UPDATE</> clause
+ (but <emphasis>not</emphasis> in the event of an <literal>ON
+ CONFLICT IGNORE</> clause), the command tag reports the number of
+ rows inserted or updated together, of the form
+<screen>
+UPSERT <replaceable>oid</replaceable> <replaceable class="parameter">count</replaceable>
</screen>
The <replaceable class="parameter">count</replaceable> is the number
of rows inserted. If <replaceable class="parameter">count</replaceable>
is exactly one, and the target table has OIDs, then
<replaceable class="parameter">oid</replaceable> is the
- <acronym>OID</acronym> assigned to the inserted row. Otherwise
- <replaceable class="parameter">oid</replaceable> is zero.
+ <acronym>OID</acronym>
+ assigned to the inserted row (but not if there is only a single
+ updated row). Otherwise <replaceable
+ class="parameter">oid</replaceable> is zero..
</para>
<para>
If the <command>INSERT</> command contains a <literal>RETURNING</>
clause, the result will be similar to that of a <command>SELECT</>
statement containing the columns and values defined in the
- <literal>RETURNING</> list, computed over the row(s) inserted by the
- command.
+ <literal>RETURNING</> list, computed over the row(s) inserted or
+ updated by the command.
</para>
</refsect1>
RETURNING *
)
INSERT INTO employees_log SELECT *, current_timestamp FROM upd;
+</programlisting>
+ </para>
+ <para>
+ Insert or update new distributors as appropriate. Assumes a unique
+ index has been defined that constrains values appearing in the
+ <literal>did</literal> column. Note that an <varname>EXCLUDED</>
+ expression is used to reference values originally proposed for
+ insertion:
+<programlisting>
+ INSERT INTO distributors (did, dname)
+ VALUES (5, 'Gizmo transglobal'), (6, 'Associated Computing, inc')
+ ON CONFLICT (did) UPDATE SET dname = EXCLUDED.dname;
</programlisting>
</para>
<para>
<programlisting>
INSERT INTO distributors (did, dname) VALUES (7, 'Redline GmbH')
ON CONFLICT (did) IGNORE;
+</programlisting>
+ </para>
+ <para>
+ Insert or update new distributors as appropriate. Example assumes
+ a unique index has been defined that constrains values appearing in
+ the <literal>did</literal> column. <literal>WHERE</> clause is
+ used to limit the rows actually updated (any existing row not
+ updated will still be locked, though):
+<programlisting>
+ -- Don't update existing distributors based in a certain ZIP code
+ INSERT INTO distributors (did, dname) VALUES (8, 'Anvil Distribution')
+ ON CONFLICT (did) UPDATE
+ SET dname = EXCLUDED.dname || ' (formerly ' || TARGET.dname || ')'
+ WHERE TARGET.zipcode != '21201';
</programlisting>
</para>
<para>
On tables and foreign tables, triggers can be defined to execute either
before or after any <command>INSERT</command>, <command>UPDATE</command>,
or <command>DELETE</command> operation, either once per modified row,
- or once per <acronym>SQL</acronym> statement.
- <command>UPDATE</command> triggers can moreover be set to fire only if
- certain columns are mentioned in the <literal>SET</literal> clause of the
- <command>UPDATE</command> statement.
- Triggers can also fire for <command>TRUNCATE</command> statements.
- If a trigger event occurs, the trigger's function is called at the
- appropriate time to handle the event. Foreign tables do not support the
- TRUNCATE statement at all.
+ or once per <acronym>SQL</acronym> statement. If an
+ <command>INSERT</command> contains an <literal>ON CONFLICT UPDATE</>
+ clause, it is possible that the effects of a BEFORE insert trigger and
+ a BEFORE update trigger can both be applied twice, if a reference to
+ an <varname>EXCLUDED</> column appears. <command>UPDATE</command>
+ triggers can moreover be set to fire only if certain columns are
+ mentioned in the <literal>SET</literal> clause of the
+ <command>UPDATE</command> statement. Triggers can also fire for
+ <command>TRUNCATE</command> statements. If a trigger event occurs,
+ the trigger's function is called at the appropriate time to handle the
+ event. Foreign tables do not support the TRUNCATE statement at all.
</para>
<para>
be operated on.
</para>
+ <para>
+ If an <command>INSERT</command> contains an <literal>ON CONFLICT
+ UPDATE</> clause, it is possible that the effects of all row-level
+ <literal>BEFORE</> <command>INSERT</command> triggers and all
+ row-level BEFORE <command>UPDATE</command> triggers can both be
+ applied in a way that is apparent from the final state of the updated
+ row, if an <varname>EXCLUDED</> column is referenced. There need not
+ be an <varname>EXCLUDED</> column reference for both sets of BEFORE
+ row-level triggers to execute, though. The possibility of surprising
+ outcomes should be considered when there are both <literal>BEFORE</>
+ <command>INSERT</command> and <literal>BEFORE</>
+ <command>UPDATE</command> row-level triggers that both affect a row
+ being inserted/updated (this can still be problematic if the
+ modifications are more or less equivalent if they're not also
+ idempotent). Note that statement-level <command>UPDATE</command>
+ triggers are executed when <literal>ON CONFLICT UPDATE</> is
+ specified, regardless of whether or not any rows were affected by
+ the <command>UPDATE</command> (and regardless of whether the
+ alternative <command>UPDATE</command> path was ever taken). An
+ <command>INSERT</command> with an <literal>ON CONFLICT UPDATE</>
+ clause will execute statement-level <literal>BEFORE</>
+ <command>INSERT</command> triggers first, then statement-level
+ <literal>BEFORE</> <command>UPDATE</command> triggers, followed by
+ statement-level <literal>AFTER</> <command>UPDATE</command>
+ triggers and finally statement-level <literal>AFTER</>
+ <command>INSERT</command> triggers. <literal>ON CONFLICT
+ UPDATE</> is not supported on views (only <literal>ON CONFLICT
+ IGNORE</> is supported on updatable views).
+ </para>
+
<para>
Trigger functions invoked by per-statement triggers should always
return <symbol>NULL</symbol>. Trigger functions invoked by per-row
*
* Function result may be:
* HeapTupleMayBeUpdated: lock was successfully acquired
+ * HeapTupleInvisible: lock failed because tuple instantaneously invisible
* HeapTupleSelfUpdated: lock failed because tuple updated by self
* HeapTupleUpdated: lock failed because tuple updated by other xact
* HeapTupleWouldBlock: lock couldn't be acquired and wait_policy is skip
*
- * In the failure cases, the routine fills *hufd with the tuple's t_ctid,
- * t_xmax (resolving a possible MultiXact, if necessary), and t_cmax
- * (the last only for HeapTupleSelfUpdated, since we
- * cannot obtain cmax from a combocid generated by another transaction).
+ * In the failure cases other than HeapTupleInvisible, the routine fills
+ * *hufd with the tuple's t_ctid, t_xmax (resolving a possible MultiXact,
+ * if necessary), and t_cmax (the last only for HeapTupleSelfUpdated,
+ * since we cannot obtain cmax from a combocid generated by another
+ * transaction).
* See comments for struct HeapUpdateFailureData for additional info.
*
* See README.tuplock for a thorough explanation of this mechanism.
if (result == HeapTupleInvisible)
{
- UnlockReleaseBuffer(*buffer);
- elog(ERROR, "attempted to lock invisible tuple");
+ LockBuffer(*buffer, BUFFER_LOCK_UNLOCK);
+
+ /*
+ * This is possible, but only when locking a tuple for ON CONFLICT
+ * UPDATE. We return this value here rather than throwing an error in
+ * order to give that case the opportunity to throw a more specific
+ * error.
+ */
+ return HeapTupleInvisible;
}
else if (result == HeapTupleBeingUpdated)
{
F311 Schema definition statement 03 CREATE VIEW YES
F311 Schema definition statement 04 CREATE VIEW: WITH CHECK OPTION YES
F311 Schema definition statement 05 GRANT statement YES
-F312 MERGE statement NO
+F312 MERGE statement NO Consider INSERT ... ON CONFLICT UPDATE
F313 Enhanced MERGE statement NO
F314 MERGE statement with DELETE branch NO
F321 User authorization YES
static void ExplainScanTarget(Scan *plan, ExplainState *es);
static void ExplainModifyTarget(ModifyTable *plan, ExplainState *es);
static void ExplainTargetRel(Plan *plan, Index rti, ExplainState *es);
-static void show_modifytable_info(ModifyTableState *mtstate, ExplainState *es);
+static void show_modifytable_info(ModifyTableState *mtstate, List *ancestors,
+ ExplainState *es);
static void ExplainMemberNodes(List *plans, PlanState **planstates,
- List *ancestors, ExplainState *es);
+ PlanState *extraplan, List *ancestors,
+ ExplainState *es);
static void ExplainSubPlans(List *plans, List *ancestors,
const char *relationship, ExplainState *es);
static void ExplainProperty(const char *qlabel, const char *value,
ExplainPreScanMemberNodes(((ModifyTable *) plan)->plans,
((ModifyTableState *) planstate)->mt_plans,
rels_used);
+ /* Do nothing with possible auxiliary onConflict plan */
break;
case T_Append:
ExplainPreScanMemberNodes(((Append *) plan)->appendplans,
const char *custom_name = NULL;
int save_indent = es->indent;
bool haschildren;
+ bool suppresschildren = false;
switch (nodeTag(plan))
{
pname = sname = "Result";
break;
case T_ModifyTable:
- sname = "ModifyTable";
- switch (((ModifyTable *) plan)->operation)
{
- case CMD_INSERT:
- pname = operation = "Insert";
- break;
- case CMD_UPDATE:
- pname = operation = "Update";
- break;
- case CMD_DELETE:
- pname = operation = "Delete";
- break;
- default:
- pname = "???";
- break;
+ ModifyTable *mtplan;
+
+ sname = "ModifyTable";
+ mtplan = (ModifyTable *) plan;
+ switch (mtplan->operation)
+ {
+ case CMD_INSERT:
+ pname = operation = "Insert";
+ break;
+ case CMD_UPDATE:
+ if (mtplan->spec != SPEC_UPDATE)
+ {
+ pname = operation = "Update";
+ }
+ else
+ {
+ pname = operation = "Conflict Update";
+
+ /*
+ * Do not display child seq scan/result node. Quals
+ * from child will be directly attributed to
+ * ModifyTable node within show_modifytable_info(),
+ * since actual scan node is only an implementation
+ * detail; it is never executed in the conventional
+ * way.
+ */
+ suppresschildren = true;
+ }
+ break;
+ case CMD_DELETE:
+ pname = operation = "Delete";
+ break;
+ default:
+ pname = "???";
+ break;
+ }
}
break;
case T_Append:
planstate, es);
break;
case T_ModifyTable:
- show_modifytable_info((ModifyTableState *) planstate, es);
+ show_modifytable_info((ModifyTableState *) planstate, ancestors,
+ es);
+ /*
+ * When suppresschildren is set, already attributed child/scan node
+ * quals to ModifyTable node
+ */
+ if (suppresschildren)
+ {
+ ExplainCloseGroup("Plan",
+ relationship ? NULL : "Plan",
+ true, es);
+ return;
+ }
break;
case T_Hash:
show_hash_info((HashState *) planstate, es);
case T_ModifyTable:
ExplainMemberNodes(((ModifyTable *) plan)->plans,
((ModifyTableState *) planstate)->mt_plans,
- ancestors, es);
+ ((ModifyTableState *) planstate)->onConflict,
+ ancestors,
+ es);
break;
case T_Append:
ExplainMemberNodes(((Append *) plan)->appendplans,
((AppendState *) planstate)->appendplans,
- ancestors, es);
+ NULL, ancestors, es);
break;
case T_MergeAppend:
ExplainMemberNodes(((MergeAppend *) plan)->mergeplans,
((MergeAppendState *) planstate)->mergeplans,
- ancestors, es);
+ NULL, ancestors, es);
break;
case T_BitmapAnd:
ExplainMemberNodes(((BitmapAnd *) plan)->bitmapplans,
((BitmapAndState *) planstate)->bitmapplans,
- ancestors, es);
+ NULL, ancestors, es);
break;
case T_BitmapOr:
ExplainMemberNodes(((BitmapOr *) plan)->bitmapplans,
((BitmapOrState *) planstate)->bitmapplans,
- ancestors, es);
+ NULL, ancestors, es);
break;
case T_SubqueryScan:
ExplainNode(((SubqueryScanState *) planstate)->subplan, ancestors,
/*
* Show extra information for a ModifyTable node
*
- * We have two objectives here. First, if there's more than one target table
+ * We have three objectives here. First, if there's more than one target table
* or it's different from the nominal target, identify the actual target(s).
* Second, give FDWs a chance to display extra info about foreign targets.
+ * Third, show auxiliary onConflict plan quals/instrumentation without
+ * displaying implementation-level scan node.
*/
static void
-show_modifytable_info(ModifyTableState *mtstate, ExplainState *es)
+show_modifytable_info(ModifyTableState *mtstate, List *ancestors,
+ ExplainState *es)
{
ModifyTable *node = (ModifyTable *) mtstate->ps.plan;
const char *operation;
j,
es);
}
+ else if (mtstate->spec == SPEC_UPDATE)
+ {
+ PlanState *ps = (*mtstate->mt_plans);
+
+ /*
+ * Seqscan node is always used, unless optimizer determined that
+ * predicate precludes ever updating, in which case a simple Result
+ * node is possible
+ */
+ Assert(IsA(ps->plan, SeqScan) || IsA(ps->plan, Result));
+
+ /* Attribute child scan node's qual to ModifyTable node */
+ show_scan_qual(ps->plan->qual, "Filter", ps, ancestors, es);
+
+ if (ps->plan->qual)
+ show_instrumentation_count("Rows Removed by Filter", 1, ps, es);
+ }
if (labeltargets)
{
* Make sure that there is still an arbiter property list when ON CONFLICT
* IGNORE is used, and an inference specification is omitted (Non-text
* format explains will show an empty array, which seems appropriate
- * there).
+ * there). SPEC_INSERT case requires that some arbiter index is inferred,
+ * so no need do anything there.
*/
if (node->spec == SPEC_IGNORE && idxNames == NIL &&
es->format == EXPLAIN_FORMAT_TEXT)
idxNames = lappend(idxNames, "(All)");
- if (node->spec == SPEC_IGNORE)
+ if (node->spec == SPEC_IGNORE || node->spec == SPEC_INSERT)
ExplainPropertyList("Conflict Arbiter Indexes", idxNames, es);
if (labeltargets)
* we need the list in order to determine the length of the PlanState array.
*/
static void
-ExplainMemberNodes(List *plans, PlanState **planstates,
+ExplainMemberNodes(List *plans, PlanState **planstates, PlanState *extraplan,
List *ancestors, ExplainState *es)
{
int nplans = list_length(plans);
for (j = 0; j < nplans; j++)
ExplainNode(planstates[j], ancestors,
"Member", NULL, es);
+
+ if (extraplan)
+ ExplainNode(extraplan, ancestors, "Member", NULL, es);
}
/*
TupleTableSlot *newSlot;
int i;
Bitmapset *updatedCols;
- Bitmapset *keyCols;
LockTupleMode lockmode;
- /*
- * Compute lock mode to use. If columns that are part of the key have not
- * been modified, then we can use a weaker lock, allowing for better
- * concurrency.
- */
- updatedCols = GetUpdatedColumns(relinfo, estate);
- keyCols = RelationGetIndexAttrBitmap(relinfo->ri_RelationDesc,
- INDEX_ATTR_BITMAP_KEY);
- if (bms_overlap(keyCols, updatedCols))
- lockmode = LockTupleExclusive;
- else
- lockmode = LockTupleNoKeyExclusive;
+ /* Determine lock mode to use */
+ lockmode = ExecUpdateLockMode(estate, relinfo);
Assert(HeapTupleIsValid(fdw_trigtuple) ^ ItemPointerIsValid(tupleid));
if (fdw_trigtuple == NULL)
TRIGGER_EVENT_ROW |
TRIGGER_EVENT_BEFORE;
LocTriggerData.tg_relation = relinfo->ri_RelationDesc;
+ updatedCols = GetUpdatedColumns(relinfo, estate);
for (i = 0; i < trigdesc->numtriggers; i++)
{
Trigger *trigger = &trigdesc->triggers[i];
rows will result in attempts to re-update an already updated target row.
This is historical behavior and seems not worth changing.)
+
Speculative insertion
---------------------
Speculative insertion is a process that the executor manages for the benefit of
-INSERT...ON CONFLICT IGNORE. Supported indexes include nbtree unique
+INSERT...ON CONFLICT UPDATE/IGNORE. Supported indexes include nbtree unique
indexes (nbtree is currently the only amcanunique index access method), or
exclusion constraint indexes (exclusion constraints are considered a
-generalization of unique constraints).
-
-The primary user-visible goal for INSERT ... ON CONFLICT is to guarantee either
-an insert, or a conclusive determination that an insert cannot go ahead (due to
-a conclusively committed/visible conflict). A would-be conflict (and the
-associated index) are the arbiters of whether or not the alternative (IGNORE)
-path is taken. The implementation more or less tries to insert until one or
-the other of those two outcomes is reached. There are some non-obvious hazards
+generalization of unique constraints). Only ON CONFLICT IGNORE is supported
+with exclusion constraints.
+
+The primary user-visible goal for INSERT...ON CONFLICT UPDATE is to guarantee
+either an insert or update under normal operating conditions in READ COMMITTED
+mode (where serialization failures are just as unacceptable as they are with
+regular UPDATEs). A would-be conflict (and the associated index) are the
+arbiters of whether or not the alternative (UPDATE/IGNORE) path is taken. The
+implementation more or less tries to update or insert until one or the other of
+those two outcomes occurs successfully. There are some non-obvious hazards
involved that are carefully avoided. These hazards relate to concurrent
activity causing conflicts for the implementation, which must be handled.
Theoretically, some individual session could loop forever, although under high
concurrency one session always proceeds.
+There are 2 sources of conflicts for ON CONFLICT UPDATE:
+
+1. Conflicts from going to update (having found a conflict during the
+pre-check), and finding the tuple changed (which may or may not involve new,
+distinct constrained values in later tuple versions -- for simplicity, we don't
+bother with considering that). This is not a conflict that the IGNORE variant
+considers.
+
+2. Conflicts from inserting a tuple (having not found a conflict during the
+pre-check), and only then finding a conflict at insertion time (when inserting
+index tuples, and finding a conflicting one when a buffer lock is held on an
+index page in the ordinary course of insertion). This can happen if a
+concurrent insertion occurs after the pre-check, but before physical index
+tuple insertion.
+
The first step in the loop is to perform a pre-check. The indexes are scanned
for existing conflicting values. At this point, we may have to wait until the
end of another xact (or xact's promise token -- more on that later), iff it
isn't immediately conclusive that there is or is not a conflict (when we finish
-the pre-check, there is a conclusion about there either being or
-not being a conflict).
+the pre-check, there is a preliminary conclusion about there either being or
+not being a conflict -- but the conclusion only holds if there are no
+subsequent concurrent conflicts). If a conclusively committed conflict tuple
+is detected during the first step, the executor goes to lock and update the row
+(for ON CONFLICT UPDATE -- otherwise, for ON CONFLICT IGNORE, we're done). The
+TID to lock (and potentially UPDATE) can only be determined during the first
+step. If locking the row finds a concurrent conflict (which may be from a
+concurrent UPDATE that hasn't even physically inspected the arbiter index yet)
+then we restart the loop from the very beginning. We restart from scratch
+because all bets are off; it's possible that the process will find no conflict
+the second time around, and will successfully insert, or will UPDATE another
+tuple that is not even part of the same UPDATE chain as first time around.
The second step (skipped when a conflict is found) is to insert a heap tuple
and related index tuples opportunistically. This uses the same mechanism as
user-visible mutual dependency, and yet an implementation related mutual
dependency is unexpectedly introduced. The user might be left with no
reasonable way of avoiding these deadlocks, which would not be okay.
+
+
+Speculative insertion and EvalPlanQual()
+----------------------------------------
+
+Updating the tuple involves locking it first (to establish a definitive tuple
+to consider evaluating the additional UPDATE qual against). The EvalPlanQual()
+mechanism (or, rather, some associated infrastructure) is reused for the
+benefit of auxiliary UPDATE expression evaluation.
+
+Locking first deviates from how conventional UPDATEs work, but allows the
+implementation to consider the possibility of conflicts first, and then, having
+reached a definitive conclusion, separately evaluate.
+
+ExecOnConflictUpdate() is somewhat similar to EvalPlanQual(), except it locks
+the TID reported as conflicting, and upon successfully locking, installs that
+into the UPDATE's EPQ slot. There is no UPDATE chain to walk -- rather, new
+tuples to check the qual against come from continuous attempts at locking a
+tuple conclusively (avoiding conflicts). The qual (if any) is then evaluated.
+Note that at READ COMMITTED, it's possible that *no* version of the tuple is
+visible, and yet it may still be updated. Similarly, since we do not walk the
+UPDATE chain, concurrent READ COMMITTED INSERT ... ON CONFLICT UPDATE sessions
+always attempt to lock the conclusively visible tuple, without regard to any
+other tuple version (repeatable read isolation level and up must consider MVCC
+visibility, though). A further implication of this is that the
+MVCC-snapshot-visible row version is denied the opportunity to prevent the
+UPDATE from taking place, should it not pass our qual (while a later version
+does pass it). This is fundamentally similar to updating a tuple when no
+version is visible, though.
* Speculative insertion
* ---------------------
*
- * Speculative insertion is a process that the executor manages for the benefit
- * of INSERT...ON CONFLICT IGNORE. Supported indexes include nbtree unique
+ * Speculative insertion is a process that the executor manages for the benefit of
+ * INSERT...ON CONFLICT UPDATE/IGNORE. Supported indexes include nbtree unique
* indexes (nbtree is currently the only amcanunique index access method), or
* exclusion constraint indexes (exclusion constraints are considered a
- * generalization of unique constraints). Speculative insertion is a is a
- * two-phase mechanism, used to implement INSERT ... ON CONFLICT IGNORE. We
- * first insert the tuple to the heap and update the indexes as usual, but if a
- * constraint is violated, we can still back out the insertion without aborting
- * the whole transaction. In a INSERT ... ON CONFLICT statement, the tuple is
- * first inserted as usual, but if a conflict is detected, it's backed out and
- * the ON CONFLICT action is executed instead.
+ * generalization of unique constraints). Only ON CONFLICT IGNORE is supported
+ * with exclusion constraints.
+ * Speculative insertion is a is a two-phase mechanism, used to implement INSERT ...
+ * ON CONFLICT UPDATE/IGNORE. We first insert the tuple to the heap and update the
+ * indexes as usual, but if a constraint is violated, we can still back out the
+ * insertion without aborting the whole transaction. In a INSERT ... ON CONFLICT
+ * statement, the tuple is first inserted as usual, but if a conflict is detected,
+ * it's backed out and the ON CONFLICT action is executed instead.
*
* Insertion to a unique index works as usual: the index AM checks for duplicate
* keys atomically with the insertion. But instead of throwing an error on a
}
+/*
+ * ExecUpdateLockMode -- find the appropriate UPDATE tuple lock mode for a
+ * given ResultRelInfo
+ */
+LockTupleMode
+ExecUpdateLockMode(EState *estate, ResultRelInfo *relinfo)
+{
+ Bitmapset *keyCols;
+ Bitmapset *updatedCols;
+
+ /*
+ * Compute lock mode to use. If columns that are part of the key have not
+ * been modified, then we can use a weaker lock, allowing for better
+ * concurrency.
+ */
+ updatedCols = GetUpdatedColumns(relinfo, estate);
+ keyCols = RelationGetIndexAttrBitmap(relinfo->ri_RelationDesc,
+ INDEX_ATTR_BITMAP_KEY);
+
+ if (bms_overlap(keyCols, updatedCols))
+ return LockTupleExclusive;
+
+ return LockTupleNoKeyExclusive;
+}
+
/*
* ExecFindRowMark -- find the ExecRowMark struct for given rangetable index
*/
* case, so as to avoid the "Halloween problem" of
* repeated update attempts. In the latter case it might
* be sensible to fetch the updated tuple instead, but
- * doing so would require changing heap_lock_tuple as well
- * as heap_update and heap_delete to not complain about
- * updating "invisible" tuples, which seems pretty scary.
- * So for now, treat the tuple as deleted and do not
- * process.
+ * doing so would require changing heap_update and
+ * heap_delete to not complain about updating "invisible"
+ * tuples, which seems pretty scary (heap_lock_tuple will
+ * not complain, but few callers expect HeapTupleInvisible,
+ * and we're not one of them). So for now, treat the tuple
+ * as deleted and do not process.
*/
ReleaseBuffer(buffer);
return NULL;
bool *isNull, ExprDoneCond *isDone);
static Datum ExecEvalCurrentOfExpr(ExprState *exprstate, ExprContext *econtext,
bool *isNull, ExprDoneCond *isDone);
+static Datum ExecEvalExcluded(ExcludedExprState *excludedExpr,
+ ExprContext *econtext, bool *isNull,
+ ExprDoneCond *isDone);
/* ----------------------------------------------------------------
return 0; /* keep compiler quiet */
}
+/* ----------------------------------------------------------------
+ * ExecEvalExcluded
+ * ----------------------------------------------------------------
+ */
+static Datum
+ExecEvalExcluded(ExcludedExprState *excludedExpr, ExprContext *econtext,
+ bool *isNull, ExprDoneCond *isDone)
+{
+ /*
+ * ExcludedExpr is essentially an expression that adapts its single Var
+ * argument to refer to the expression context inner slot's tuple, which is
+ * reserved for the purpose of referencing EXCLUDED.* tuples within ON
+ * CONFLICT UPDATE auxiliary queries' EPQ expression context (ON CONFLICT
+ * UPDATE makes special use of the EvalPlanQual() mechanism to update).
+ *
+ * nodeModifyTable.c assigns its own table slot in the auxiliary queries'
+ * EPQ expression state (originating in the parent INSERT node) on the
+ * assumption that it may only be used by ExcludedExpr, and on the
+ * assumption that the inner slot is not otherwise useful. This occurs in
+ * advance of the expression evaluation for UPDATE (which calls here are
+ * part of) once per slot proposed for insertion, and works because of
+ * restrictions on the structure of ON CONFLICT UPDATE auxiliary queries.
+ *
+ * Just evaluate nested Var.
+ */
+ return ExecEvalScalarVar(excludedExpr->arg, econtext, isNull, isDone);
+}
/*
* ExecEvalExprSwitchContext
state = (ExprState *) makeNode(ExprState);
state->evalfunc = ExecEvalCurrentOfExpr;
break;
+ case T_ExcludedExpr:
+ {
+ ExcludedExpr *excludedexpr = (ExcludedExpr *) node;
+ ExcludedExprState *cstate = makeNode(ExcludedExprState);
+ Var *contained = (Var *) excludedexpr->arg;
+
+ /*
+ * varno forced to INNER_VAR -- see remarks within
+ * ExecLockUpdateTuple().
+ *
+ * We rely on the assumption that the only place that
+ * ExcludedExpr may appear is where EXCLUDED Var references
+ * originally appeared after parse analysis. The rewriter
+ * replaces these with ExcludedExpr that reference the
+ * corresponding Var within the ON CONFLICT UPDATE target RTE.
+ */
+ Assert(IsA(contained, Var));
+
+ contained->varno = INNER_VAR;
+ cstate->arg = ExecInitExpr((Expr *) contained, parent);
+ state = (ExprState *) cstate;
+ state->evalfunc = (ExprStateEvalFunc) ExecEvalExcluded;
+ }
+ break;
case T_TargetEntry:
{
TargetEntry *tle = (TargetEntry *) node;
* case, so as to avoid the "Halloween problem" of repeated
* update attempts. In the latter case it might be sensible
* to fetch the updated tuple instead, but doing so would
- * require changing heap_lock_tuple as well as heap_update and
- * heap_delete to not complain about updating "invisible"
- * tuples, which seems pretty scary. So for now, treat the
- * tuple as deleted and do not process.
+ * require changing heap_update and heap_delete to not complain
+ * about updating "invisible" tuples, which seems pretty scary
+ * (heap_lock_tuple will not complain, but few callers expect
+ * HeapTupleInvisible, and we're not one of them). So for now,
+ * treat the tuple as deleted and do not process.
*/
goto lnext;
#include "utils/tqual.h"
+static bool ExecOnConflictUpdate(ResultRelInfo *resultRelInfo,
+ ItemPointer conflictTid,
+ TupleTableSlot *planSlot,
+ TupleTableSlot *insertSlot,
+ ModifyTableState *onConflict,
+ EState *estate,
+ bool canSetTag,
+ TupleTableSlot **returning);
+
/*
* Verify that the tuples to be produced by INSERT or UPDATE match the
* target relation's rowtype
static TupleTableSlot *
ExecInsert(TupleTableSlot *slot,
TupleTableSlot *planSlot,
+ ModifyTableState *onConflict,
List *arbiterIndexes,
SpecCmd spec,
EState *estate,
/*
* Committed conflict tuple found.
*
+ * In case of ON CONFLICT UPDATE, execute the UPDATE part.
+ * Be prepared to retry if the UPDATE fails because of another
+ * concurrent UPDATE/DELETE to the conflict tuple.
+ */
+ if (spec == SPEC_INSERT)
+ {
+ TupleTableSlot *returning = NULL;
+
+ if (ExecOnConflictUpdate(resultRelInfo, &conflictTid,
+ planSlot, slot, onConflict,
+ estate, canSetTag, &returning))
+ return returning;
+ else
+ goto vlock;
+ }
+ /*
* In case of ON CONFLICT IGNORE, do nothing. However, verify
* that the tuple is visible to the executor's MVCC snapshot at
* higher isolation levels.
*/
- if (spec == SPEC_IGNORE)
+ else
{
+ Assert(spec == SPEC_IGNORE);
ExecCheckHeapTupleVisible(estate, resultRelInfo,
&conflictTid);
return NULL;
return NULL;
}
+/*
+ * ExecOnConflictUpdate --- execute UPDATE part of INSERT ON CONFLICT UPDATE
+ *
+ * Try to lock tuple for update as part of speculative insertion. If
+ * a qual originating from ON CONFLICT UPDATE is satisfied, update
+ * (but still lock row, even though it may not satisfy estate's
+ * snapshot).
+ *
+ * Returns true if if we're done (with or without an update), or false if
+ * the caller must retry the INSERT from scratch.
+ */
+static bool
+ExecOnConflictUpdate(ResultRelInfo *resultRelInfo,
+ ItemPointer conflictTid,
+ TupleTableSlot *planSlot,
+ TupleTableSlot *insertSlot,
+ ModifyTableState *onConflict,
+ EState *estate,
+ bool canSetTag,
+ TupleTableSlot **returning)
+{
+ Relation relation = resultRelInfo->ri_RelationDesc;
+ HeapTupleData tuple;
+ HeapTuple copyTuple = NULL;
+ HeapUpdateFailureData hufd;
+ HTSU_Result test;
+ Buffer buffer;
+ TupleTableSlot *slot;
+ ExprContext *econtext;
+ LockTupleMode lockmode;
+
+ /* Determine lock mode to use */
+ lockmode = ExecUpdateLockMode(estate, resultRelInfo);
+
+ /*
+ * Lock tuple for update.
+ *
+ * Like EvalPlanQualFetch(), don't follow updates. There is no actual
+ * benefit to doing so, since as discussed below, a conflict invalidates
+ * our previous conclusion that the tuple is the conclusively committed
+ * conflicting tuple.
+ */
+ tuple.t_self = *conflictTid;
+ test = heap_lock_tuple(relation, &tuple, estate->es_output_cid,
+ lockmode, LockWaitBlock, false, &buffer,
+ &hufd);
+
+ if (test == HeapTupleMayBeUpdated)
+ copyTuple = heap_copytuple(&tuple);
+
+ switch (test)
+ {
+ case HeapTupleInvisible:
+
+ /*
+ * This may occur when an instantaneously invisible tuple is
+ * blamed as a conflict because multiple rows are inserted with
+ * the same constrained values.
+ *
+ * This is somewhat similar to the ExecUpdate()
+ * HeapTupleSelfUpdated case, although the user-visible behavior
+ * differs (auxiliary UPDATEs throw an error).
+ *
+ * We cannot proceed, because to do so would leave users open to
+ * the risk that the same row will be updated a second time in the
+ * same command; allowing a second update affecting a single row
+ * within the same command a second time would leave the update
+ * order undefined. It is the user's responsibility to resolve
+ * these self-duplicates in advance of proposing for insertion a
+ * set of tuples. These problems are why SQL-2003 similarly
+ * specifies that for SQL MERGE, an exception must be raised in the
+ * event of an attempt to update the same row twice. SQL MERGE is
+ * similarly "deterministic".
+ */
+ if (TransactionIdIsCurrentTransactionId(HeapTupleHeaderGetXmin(tuple.t_data)))
+ ereport(ERROR,
+ (errcode(ERRCODE_CARDINALITY_VIOLATION),
+ errmsg("ON CONFLICT UPDATE command could not lock/update self-inserted tuple"),
+ errhint("Ensure that no rows proposed for insertion within the same command have duplicate constrained values.")));
+
+ /* This shouldn't happen */
+ elog(ERROR, "attempted to lock invisible tuple");
+ return false; /* keep compiler quiet */
+ case HeapTupleSelfUpdated:
+
+ /*
+ * This path should never be taken, since BEFORE triggers fire
+ * prior to speculative insertion. Since a dirty snapshot is used
+ * to find possible conflict tuples, speculative insertion could
+ * not have seen the old/MVCC-current row version at all (even if
+ * it was only rendered old by this same command).
+ */
+ elog(ERROR, "unexpected self-updated tuple");
+ return false; /* keep compiler quiet */
+ case HeapTupleMayBeUpdated:
+
+ /*
+ * Success -- we're done, as tuple is locked. Verify that the
+ * tuple is visible to our MVCC snapshot if the current isolation
+ * level mandates that. In READ COMMITTED mode, we can lock and
+ * update a (committed) tuple still in progress according to our
+ * snapshot, but higher isolation levels cannot avail of that, and
+ * must actively defend against doing so. We might get a
+ * serialization failure within ExecUpdate() anyway if this step
+ * was skipped, but this cannot be relied on, for example because
+ * the auxiliary WHERE clause happened to not be satisfied.
+ */
+ ExecCheckHeapTupleVisible(estate, resultRelInfo,
+ &tuple.t_data->t_ctid);
+
+ /*
+ * This loosening of snapshot isolation for the benefit of READ
+ * COMMITTED speculative insertions is used consistently:
+ * speculative quals are only tested against the already locked
+ * tuple. It would be rather inconsistent to UPDATE when no tuple
+ * version is MVCC-visible (which seems inevitable since we must
+ * *do something* there, and "READ COMMITTED serialization
+ * failures" are unappealing), while also avoiding updating here
+ * entirely on the basis of a non-conclusive tuple version (the
+ * version that happens to be visible to this command's MVCC
+ * snapshot, or some subsequent non-conclusive version).
+ *
+ * In other words: Only the final, conclusive, locked tuple (which
+ * must have the same values within the relevant constrained
+ * attribute(s) as those in the tuple proposed for insertion)
+ * matters.
+ */
+
+ /* must provide our own instrumentation support */
+ if (onConflict->ps.instrument)
+ InstrStartNode(onConflict->ps.instrument);
+
+ /*
+ * Conceptually, the parent ModifyTable is like a relation scan
+ * node that uses a dirty snapshot, returning rows which the
+ * auxiliary plan must operate on.
+ *
+ * Note that this code path merely re-uses some parts of the
+ * EvalPlanQual() infrastructure; it does not really use
+ * EvalPlanQual(), because the UPDATE chain is not actually walked.
+ */
+ EvalPlanQualBegin(&onConflict->mt_epqstate, onConflict->ps.state);
+
+ /*
+ * Save EPQ expression context. Auxiliary plan's scan node (which
+ * would have been just initialized by EvalPlanQualBegin() on the
+ * first time through here per query) cannot fail to provide one.
+ */
+ econtext = onConflict->mt_epqstate.planstate->ps_ExprContext;
+
+ /*
+ * UPDATE affects the same ResultRelation as INSERT in the context
+ * of ON CONFLICT UPDATE, so parent's target rti can be used
+ */
+ Assert(resultRelInfo->ri_RangeTableIndex ==
+ onConflict->ps.state->es_result_relation_info->ri_RangeTableIndex);
+
+ EvalPlanQualSetTuple(&onConflict->mt_epqstate,
+ resultRelInfo->ri_RangeTableIndex, copyTuple);
+
+ /*
+ * Make available excluded-from-insertion tuple (EXCLUDED.*) for
+ * referencing within UPDATE expression (that is, make available a
+ * slot with that tuple, possibly already modified by BEFORE INSERT
+ * row triggers).
+ *
+ * This is for the benefit of any ExcludedExpr that may appear
+ * within the auxiliary UPDATE's targetlist or WHERE clause (the
+ * EXCLUDED.* tuple is referenced as an ExcludedExpr). The nested
+ * ExcludedExpr's Var is set during ExcludedExpr initialization to
+ * have an INNER_VAR varno on the assumption that the inner slot of
+ * the EPQ scanstate's expression context will be found to contain
+ * this excluded tuple slot (that is, on the assumption that during
+ * expression evaluation, ecxt_innertuple will have been assigned
+ * the insertSlot here, after ExcludedExpr initialization but in
+ * advance of this expression evaluation).
+ *
+ * See handling of ExcludedExpr within handleRewrite.c and
+ * execQual.c.
+ */
+ econtext->ecxt_innertuple = insertSlot;
+
+ /*
+ * Execute auxiliary UPDATE for slot proposed for insertion, to
+ * generate new tuple version to supersede TARGET.* tuple.
+ *
+ * This may include expression evaluation of ExcludedExpr (which
+ * occurs in no other context).
+ */
+ slot = EvalPlanQualNext(&onConflict->mt_epqstate);
+
+ if (!TupIsNull(slot))
+ *returning = ExecUpdate(&tuple.t_data->t_ctid, NULL,
+ slot, planSlot,
+ &onConflict->mt_epqstate,
+ onConflict->ps.state, canSetTag);
+
+ ReleaseBuffer(buffer);
+
+ /*
+ * As when executing an UPDATE's ModifyTable node in the
+ * conventional manner, reset the per-output-tuple ExprContext
+ */
+ ResetPerTupleExprContext(onConflict->ps.state);
+
+ /* must provide our own instrumentation support */
+ if (onConflict->ps.instrument)
+ InstrStopNode(onConflict->ps.instrument, *returning ? 1 : 0);
+
+ return true;
+ case HeapTupleUpdated:
+ if (IsolationUsesXactSnapshot())
+ ereport(ERROR,
+ (errcode(ERRCODE_T_R_SERIALIZATION_FAILURE),
+ errmsg("could not serialize access due to concurrent update")));
+
+ /*
+ * Tell caller to try again from the very start. We don't use the
+ * usual EvalPlanQual() looping pattern here, fundamentally
+ * because we don't have a useful qual to verify the next tuple
+ * with. Our "qual" is really any user-supplied qual AND the
+ * unique constraint "col OP value" implied by arbiter indexes.
+ * However, because of the selective evaluation of the former
+ * "qual" (the interactions with MVCC and row locking), this is an
+ * over-simplification.
+ *
+ * We might devise a means of verifying binary equality across an
+ * UPDATE chain (in respect of indexed attributes) in a similar
+ * manner to HOT codepaths, but this would only sometimes avoid
+ * problems. It might well not be good enough, and it seems
+ * unlikely that working harder here is worthwhile.
+ *
+ * At this point, all bets are off -- it might actually turn out
+ * to be okay to proceed with insertion instead of locking now
+ * (the tuple we attempted to lock could have been deleted, for
+ * example). On the other hand, it might not be okay, but for an
+ * entirely different reason, with an entirely separate TID to
+ * blame and lock. This TID may not even be part of the same
+ * update chain.
+ */
+ ReleaseBuffer(buffer);
+ return false;
+ default:
+ elog(ERROR, "unrecognized heap_lock_tuple status: %u", test);
+ }
+
+ return false;
+}
+
/*
* Process BEFORE EACH STATEMENT triggers
{
case CMD_INSERT:
ExecBSInsertTriggers(node->ps.state, node->resultRelInfo);
+ if (node->spec == SPEC_INSERT)
+ ExecBSUpdateTriggers(node->onConflict->state,
+ node->resultRelInfo);
break;
case CMD_UPDATE:
ExecBSUpdateTriggers(node->ps.state, node->resultRelInfo);
switch (node->operation)
{
case CMD_INSERT:
+ if (node->spec == SPEC_INSERT)
+ ExecASUpdateTriggers(node->onConflict->state,
+ node->resultRelInfo);
ExecASInsertTriggers(node->ps.state, node->resultRelInfo);
break;
case CMD_UPDATE:
{
EState *estate = node->ps.state;
CmdType operation = node->operation;
+ ModifyTableState *onConflict = (ModifyTableState *) node->onConflict;
ResultRelInfo *saved_resultRelInfo;
ResultRelInfo *resultRelInfo;
PlanState *subplanstate;
switch (operation)
{
case CMD_INSERT:
- slot = ExecInsert(slot, planSlot, node->arbiterIndexes,
- node->spec, estate, node->canSetTag);
+ slot = ExecInsert(slot, planSlot, onConflict,
+ node->arbiterIndexes, node->spec, estate,
+ node->canSetTag);
break;
case CMD_UPDATE:
slot = ExecUpdate(tupleid, oldtuple, slot, planSlot,
{
ModifyTableState *mtstate;
CmdType operation = node->operation;
+ Plan *onConflictPlan = node->onConflictPlan;
int nplans = list_length(node->plans);
ResultRelInfo *saved_resultRelInfo;
ResultRelInfo *resultRelInfo;
}
break;
case CMD_UPDATE:
+ junk_filter_needed = (mtstate->spec == SPEC_NONE);
+ break;
case CMD_DELETE:
junk_filter_needed = true;
break;
}
else
{
- if (operation == CMD_INSERT)
+ if (operation == CMD_INSERT || operation == CMD_UPDATE)
ExecCheckPlanOutput(mtstate->resultRelInfo->ri_RelationDesc,
subplan->targetlist);
}
}
+ /* Initialize auxiliary ModifyTable node, for ON CONFLICT UPDATE */
+ if (onConflictPlan)
+ {
+ Assert(mtstate->spec == SPEC_INSERT);
+
+ /*
+ * ExecModifyTable() is never called for auxiliary update
+ * ModifyTableState. Execution of the auxiliary plan is driven by its
+ * parent in an ad-hoc fashion.
+ */
+ mtstate->onConflict = ExecInitNode(onConflictPlan, estate, eflags);
+ }
+
/*
* Set up a tuple table slot for use for trigger output tuples. In a plan
* containing multiple ModifyTable nodes, all can share one such slot, so
* ModifyTable node too, but there's no need.) Note the use of lcons not
* lappend: we need later-initialized ModifyTable nodes to be shut down
* before earlier ones. This ensures that we don't throw away RETURNING
- * rows that need to be seen by a later CTE subplan.
+ * rows that need to be seen by a later CTE subplan. Do not append an
+ * auxiliary ON CONFLICT UPDATE node either, since it must have a parent
+ * SPEC_INSERT ModifyTable node that it is auxiliary to that directly
+ * drives execution (any !canSetTag parent will be appended here, though).
+ * If the auxiliary plan must project updated rows for RETURNING, that will
+ * occur through the parent.
*/
- if (!mtstate->canSetTag)
+ if (!mtstate->canSetTag && mtstate->spec != SPEC_UPDATE)
estate->es_auxmodifytables = lcons(mtstate,
estate->es_auxmodifytables);
*/
for (i = 0; i < node->mt_nplans; i++)
ExecEndNode(node->mt_plans[i]);
+
+ ExecEndNode(node->onConflict);
}
void
COPY_NODE_FIELD(plans);
COPY_SCALAR_FIELD(spec);
COPY_NODE_FIELD(arbiterIndexes);
+ COPY_NODE_FIELD(onConflictPlan);
COPY_NODE_FIELD(withCheckOptionLists);
COPY_NODE_FIELD(returningLists);
COPY_NODE_FIELD(fdwPrivLists);
return newnode;
}
+/*
+ * _copyExcludedExpr
+ */
+static ExcludedExpr *
+_copyExcludedExpr(const ExcludedExpr *from)
+{
+ ExcludedExpr *newnode = makeNode(ExcludedExpr);
+
+ COPY_NODE_FIELD(arg);
+
+ return newnode;
+}
+
/*
* _copyInferenceElem
*/
COPY_SCALAR_FIELD(specclause);
COPY_NODE_FIELD(infer);
+ COPY_NODE_FIELD(updatequery);
COPY_LOCATION_FIELD(location);
return newnode;
COPY_SCALAR_FIELD(specClause);
COPY_NODE_FIELD(arbiterElems);
COPY_NODE_FIELD(arbiterWhere);
+ COPY_NODE_FIELD(onConflict);
COPY_NODE_FIELD(returningList);
COPY_NODE_FIELD(groupClause);
COPY_NODE_FIELD(havingQual);
case T_CurrentOfExpr:
retval = _copyCurrentOfExpr(from);
break;
+ case T_ExcludedExpr:
+ retval = _copyExcludedExpr(from);
+ break;
case T_InferenceElem:
retval = _copyInferenceElem(from);
break;
return true;
}
+static bool
+_equalExcludedExpr(const ExcludedExpr *a, const ExcludedExpr *b)
+{
+ COMPARE_NODE_FIELD(arg);
+
+ return true;
+}
+
static bool
_equalTargetEntry(const TargetEntry *a, const TargetEntry *b)
{
COMPARE_SCALAR_FIELD(specClause);
COMPARE_NODE_FIELD(arbiterElems);
COMPARE_NODE_FIELD(arbiterWhere);
+ COMPARE_NODE_FIELD(onConflict);
COMPARE_NODE_FIELD(returningList);
COMPARE_NODE_FIELD(groupClause);
COMPARE_NODE_FIELD(havingQual);
{
COMPARE_SCALAR_FIELD(specclause);
COMPARE_NODE_FIELD(infer);
+ COMPARE_NODE_FIELD(updatequery);
COMPARE_LOCATION_FIELD(location);
return true;
case T_CurrentOfExpr:
retval = _equalCurrentOfExpr(a, b);
break;
+ case T_ExcludedExpr:
+ retval = _equalExcludedExpr(a, b);
+ break;
case T_InferenceElem:
retval = _equalInferenceElem(a, b);
break;
case T_CurrentOfExpr:
type = BOOLOID;
break;
+ case T_ExcludedExpr:
+ {
+ const ExcludedExpr *n = (const ExcludedExpr *) expr;
+
+ type = exprType((Node *) n->arg);
+ }
+ break;
case T_InferenceElem:
{
const InferenceElem *n = (const InferenceElem *) expr;
return ((const CoerceToDomainValue *) expr)->typeMod;
case T_SetToDefault:
return ((const SetToDefault *) expr)->typeMod;
+ case T_ExcludedExpr:
+ {
+ const ExcludedExpr *n = (const ExcludedExpr *) expr;
+
+ return ((const Var *) n->arg)->vartypmod;
+ }
case T_PlaceHolderVar:
return exprTypmod((Node *) ((const PlaceHolderVar *) expr)->phexpr);
default:
case T_CurrentOfExpr:
coll = InvalidOid; /* result is always boolean */
break;
+ case T_ExcludedExpr:
+ coll = exprCollation((Node *) ((const ExcludedExpr *) expr)->arg);
+ break;
case T_InferenceElem:
coll = exprCollation((Node *) ((const InferenceElem *) expr)->expr);
break;
case T_CurrentOfExpr:
Assert(!OidIsValid(collation)); /* result is always boolean */
break;
+ case T_ExcludedExpr:
+ {
+ Var *v = (Var *) ((ExcludedExpr *) expr)->arg;
+ v->varcollid = collation;
+ }
+ break;
default:
elog(ERROR, "unrecognized node type: %d", (int) nodeTag(expr));
break;
/* just use argument's location */
loc = exprLocation((Node *) ((const PlaceHolderVar *) expr)->phexpr);
break;
+ case T_ExcludedExpr:
+ /* just use nested expr's location */
+ loc = exprLocation((Node *) ((const ExcludedExpr *) expr)->arg);
+ break;
case T_InferenceElem:
/* just use nested expr's location */
loc = exprLocation((Node *) ((const InferenceElem *) expr)->expr);
break;
case T_PlaceHolderVar:
return walker(((PlaceHolderVar *) node)->phexpr, context);
+ case T_ExcludedExpr:
+ return walker(((ExcludedExpr *) node)->arg, context);
case T_InferenceElem:
return walker(((InferenceElem *) node)->expr, context);
case T_AppendRelInfo:
return true;
if (walker(query->arbiterWhere, context))
return true;
+ if (walker(query->onConflict, context))
+ return true;
if (walker((Node *) query->returningList, context))
return true;
if (walker((Node *) query->jointree, context))
return (Node *) newnode;
}
break;
+ case T_ExcludedExpr:
+ {
+ ExcludedExpr *excludedexpr = (ExcludedExpr *) node;
+ ExcludedExpr *newnode;
+
+ FLATCOPY(newnode, excludedexpr, ExcludedExpr);
+ MUTATE(newnode->arg, newnode->arg, Node *);
+ return (Node *) newnode;
+ }
+ break;
case T_InferenceElem:
{
InferenceElem *inferenceelemdexpr = (InferenceElem *) node;
MUTATE(query->withCheckOptions, query->withCheckOptions, List *);
MUTATE(query->arbiterElems, query->arbiterElems, List *);
MUTATE(query->arbiterWhere, query->arbiterWhere, Node *);
+ MUTATE(query->onConflict, query->onConflict, Node *);
MUTATE(query->returningList, query->returningList, List *);
MUTATE(query->jointree, query->jointree, FromExpr *);
MUTATE(query->setOperations, query->setOperations, Node *);
if (walker(stmt->infer, context))
return true;
+ if (walker(stmt->updatequery, context))
+ return true;
}
break;
case T_CommonTableExpr:
WRITE_NODE_FIELD(plans);
WRITE_ENUM_FIELD(spec, SpecType);
WRITE_NODE_FIELD(arbiterIndexes);
+ WRITE_NODE_FIELD(onConflictPlan);
WRITE_NODE_FIELD(withCheckOptionLists);
WRITE_NODE_FIELD(returningLists);
WRITE_NODE_FIELD(fdwPrivLists);
WRITE_INT_FIELD(cursor_param);
}
+static void
+_outExcludedExpr(StringInfo str, const ExcludedExpr *node)
+{
+ WRITE_NODE_TYPE("EXCLUDED");
+
+ WRITE_NODE_FIELD(arg);
+}
+
static void
_outInferenceElem(StringInfo str, const InferenceElem *node)
{
WRITE_ENUM_FIELD(specClause, SpecType);
WRITE_NODE_FIELD(arbiterElems);
WRITE_NODE_FIELD(arbiterWhere);
+ WRITE_NODE_FIELD(onConflict);
WRITE_NODE_FIELD(returningList);
WRITE_NODE_FIELD(groupClause);
WRITE_NODE_FIELD(havingQual);
case T_CurrentOfExpr:
_outCurrentOfExpr(str, obj);
break;
+ case T_ExcludedExpr:
+ _outExcludedExpr(str, obj);
+ break;
case T_InferenceElem:
_outInferenceElem(str, obj);
break;
READ_ENUM_FIELD(specClause, SpecCmd);
READ_NODE_FIELD(arbiterElems);
READ_NODE_FIELD(arbiterWhere);
+ READ_NODE_FIELD(onConflict);
READ_NODE_FIELD(returningList);
READ_NODE_FIELD(groupClause);
READ_NODE_FIELD(havingQual);
READ_DONE();
}
+/*
+ * _readExcludedExpr
+ */
+static ExcludedExpr *
+_readExcludedExpr(void)
+{
+ READ_LOCALS(ExcludedExpr);
+
+ READ_NODE_FIELD(arg);
+
+ READ_DONE();
+}
+
/*
* _readInferenceElem
*/
return_value = _readSetToDefault();
else if (MATCH("CURRENTOFEXPR", 13))
return_value = _readCurrentOfExpr();
+ else if (MATCH("EXCLUDED", 8))
+ return_value = _readExcludedExpr();
else if (MATCH("INFERENCEELEM", 13))
return_value = _readInferenceElem();
else if (MATCH("TARGETENTRY", 11))
/*
* We don't support pushing join clauses into the quals of a tidscan, but
* it could still have required parameterization due to LATERAL refs in
- * its tlist.
+ * its tlist. To be tidy, we disallow TID scans as the unexecuted scan
+ * node of an ON CONFLICT UPDATE auxiliary query, even though there is no
+ * reason to think that would be harmful; the optimizer should always
+ * prefer a SeqScan or Result node (actually, we assert that it's one of
+ * those two in several places, so accepting TID scans would break those).
*/
required_outer = rel->lateral_relids;
tidquals = TidQualFromRestrictinfo(rel->baserestrictinfo, rel->relid);
- if (tidquals)
+ if (tidquals && root->parse->specClause != SPEC_UPDATE)
add_path(rel, (Path *) create_tidscan_path(root, rel, tidquals,
required_outer));
}
Index nominalRelation,
List *resultRelations, List *subplans,
List *withCheckOptionLists, List *returningLists,
- List *rowMarks, SpecCmd spec, int epqParam)
+ List *rowMarks, Plan *onConflictPlan, SpecCmd spec,
+ int epqParam)
{
ModifyTable *node = makeNode(ModifyTable);
Plan *plan = &node->plan;
node->plans = subplans;
node->spec = spec;
node->arbiterIndexes = NIL;
+ node->onConflictPlan = onConflictPlan;
node->withCheckOptionLists = withCheckOptionLists;
node->returningLists = returningLists;
node->rowMarks = rowMarks;
withCheckOptionLists,
returningLists,
rowMarks,
+ NULL,
parse->specClause,
SS_assign_special_param(root));
+
+ if (parse->onConflict)
+ {
+ Query *conflictQry = (Query *) parse->onConflict;
+ ModifyTable *parent = (ModifyTable *) plan;
+
+ /*
+ * An ON CONFLICT UPDATE query is a subquery of its parent
+ * INSERT ModifyTable, but isn't formally a subplan -- it's an
+ * "auxiliary" plan.
+ *
+ * During execution, the auxiliary plan state is used to
+ * execute the UPDATE query in an ad-hoc manner, driven by the
+ * parent. The executor will only ever execute the auxiliary
+ * plan through its parent. onConflictPlan is "auxiliary" to
+ * its parent in the sense that it's strictly encapsulated
+ * from other code (for example, the executor does not
+ * separately track it within estate as a plan that needs to
+ * have execution finished when it appears within a
+ * data-modifying CTE -- only the parent is specifically
+ * tracked for that purpose).
+ *
+ * There is a fundamental nexus between parent and auxiliary
+ * plans that makes a fully unified representation seem
+ * compelling (a "CMD_UPSERT" ModifyTable plan and Query).
+ * That would obviate the need to specially track auxiliary
+ * state across all stages of execution just for this case;
+ * the optimizer would then not have to generate a
+ * fully-formed, independent UPDATE subquery plan (with a
+ * scanstate only useful for EvalPlanQual() re-evaluation).
+ * However, it's convenient to plan each ModifyTable
+ * separately, as doing so maximizes code reuse. The
+ * alternative must be to introduce abstractions that (for
+ * example) allow a single "CMD_UPSERT" ModifyTable to have
+ * two distinct types of targetlist (that will need to be
+ * processed differently during parsing and rewriting anyway).
+ * The auxiliary UPDATE plan is a good trade-off between a
+ * fully-fledged "CMD_UPSERT" representation, and the opposite
+ * extreme of tracking two separate ModifyTable nodes, joined
+ * by a contrived join type, with (for example) odd properties
+ * around tuple visibility not well encapsulated. A contrived
+ * join based design would also necessitate teaching
+ * ModifyTable nodes to support rescan just for the benefit of
+ * ON CONFLICT UPDATE.
+ */
+ parent->onConflictPlan = subquery_planner(glob, conflictQry,
+ root, hasRecursion,
+ 0, NULL);
+ }
}
}
withCheckOptionLists,
returningLists,
rowMarks,
+ NULL,
parse->specClause,
SS_assign_special_param(root));
}
* global list.
*/
splan->resultRelIndex = list_length(root->glob->resultRelations);
- root->glob->resultRelations =
- list_concat(root->glob->resultRelations,
- list_copy(splan->resultRelations));
+
+ if (!splan->onConflictPlan)
+ {
+ /*
+ * Only actually append result relation for non-auxiliary
+ * ModifyTable plans
+ */
+ root->glob->resultRelations =
+ list_concat(root->glob->resultRelations,
+ list_copy(splan->resultRelations));
+ }
+ else
+ {
+ /*
+ * Adjust rtoffset passed to child, to compensate for
+ * dummy RTE left by EXCLUDED.* alias in auxiliary plan.
+ * Auxiliary plan will target same resultRelation from
+ * flattened range table as its parent.
+ */
+ splan->onConflictPlan =
+ set_plan_refs(root, splan->onConflictPlan,
+ rtoffset - PRS2_OLD_VARNO);
+
+ /*
+ * Set up the visible plan targetlist as being the same as
+ * the parent. Again, this is for the use of EXPLAIN only.
+ */
+ splan->onConflictPlan->targetlist = splan->plan.targetlist;
+ }
}
break;
case T_Append:
valid_params,
scan_params));
}
+
+ /*
+ * No need to directly handle onConflictPlan here, since it
+ * cannot have params (due to parse analysis enforced
+ * restrictions prohibiting subqueries).
+ */
}
break;
/*
* Make list of indexes. Ignore indexes on system catalogs if told to.
- * Don't bother with indexes for an inheritance parent, either.
+ * Don't bother with indexes for an inheritance parent or speculative
+ * insertion UPDATE auxiliary Query, either (actually, auxiliary UPDATE
+ * plans with index-only scans must be avoided, so this is not just about
+ * saving cycles).
*/
if (inhparent ||
- (IgnoreSystemIndexes && IsSystemRelation(relation)))
+ (IgnoreSystemIndexes && IsSystemRelation(relation)) ||
+ root->parse->specClause == SPEC_UPDATE)
hasindex = false;
else
hasindex = relation->rd_rel->relhasindex;
/* Result */
List *candidates = NIL;
- Assert(parse->specClause == SPEC_IGNORE);
+ Assert(parse->specClause == SPEC_INSERT ||
+ parse->specClause == SPEC_IGNORE);
/*
* We need not lock the relation since it was already locked, either by
qry->rtable = pstate->p_rtable;
qry->jointree = makeFromExpr(pstate->p_joinlist, qual);
qry->specClause = SPEC_NONE;
+ qry->onConflict = NULL;
qry->hasSubLinks = pstate->p_hasSubLinks;
qry->hasWindowFuncs = pstate->p_hasWindowFuncs;
qry->commandType = CMD_INSERT;
pstate->p_is_insert = true;
+ pstate->p_is_speculative = spec != SPEC_NONE;
/* process the WITH clause independently of all else */
if (stmt->withClause)
sub_namespace = NIL;
}
+ /* INSERT with an ON CONFLICT UPDATE clause forces the "target" alias */
+ if (spec == SPEC_INSERT)
+ stmt->relation->alias = makeAlias("target", NIL);
+
/*
* Must get write lock on INSERT target table before scanning SELECT, else
* we will grab the wrong kind of initial lock if the target table is also
* mentioned in the SELECT part. Note that the target table is not added
- * to the joinlist or namespace.
+ * to the joinlist or namespace. Note also that additional requiredPerms
+ * will be appended to the target RTE iff there is an auxiliary UPDATE.
*/
qry->resultRelation = setTargetTable(pstate, stmt->relation,
false, false, ACL_INSERT);
qry->specClause = spec;
qry->hasSubLinks = pstate->p_hasSubLinks;
+ qry->onConflict = NULL;
if (stmt->confClause)
{
+ /*
+ * ON CONFLICT UPDATE requires special parse analysis of auxiliary
+ * update Query
+ */
+ if (stmt->confClause->updatequery)
+ {
+ ParseState *sub_pstate = make_parsestate(pstate);
+ Query *uqry;
+
+ /*
+ * The optimizer is not prepared to accept a subquery RTE for a
+ * non-CMD_SELECT Query. The CMD_UPDATE Query is tracked as
+ * special auxiliary state, while there is more or less analogous
+ * auxiliary state tracked in later stages of query execution.
+ *
+ * Parent canSetTag only ever actually consulted, so no need to
+ * set that here.
+ */
+ uqry = transformStmt(sub_pstate, stmt->confClause->updatequery);
+ Assert(uqry->commandType == CMD_UPDATE &&
+ uqry->specClause == SPEC_UPDATE);
+
+ /* Save auxiliary query */
+ qry->onConflict = (Node *) uqry;
+
+ free_parsestate(sub_pstate);
+ }
+
/*
* Perform parse analysis of arbiter columns/expressions. These are
* later used to infer a unique index which arbitrates whether or not
qry->rtable = pstate->p_rtable;
qry->jointree = makeFromExpr(pstate->p_joinlist, qual);
qry->specClause = SPEC_NONE;
+ qry->onConflict = NULL;
qry->hasSubLinks = pstate->p_hasSubLinks;
qry->hasWindowFuncs = pstate->p_hasWindowFuncs;
Node *qual;
ListCell *origTargetList;
ListCell *tl;
+ bool InhOption;
qry->commandType = CMD_UPDATE;
pstate->p_is_update = true;
+ /* for auxiliary UPDATEs, visit parent INSERT to set target table */
+ pstate->p_is_speculative = (stmt->relation == NULL);
+
/* process the WITH clause independently of all else */
if (stmt->withClause)
{
qry->hasModifyingCTE = pstate->p_hasModifyingCTE;
}
+ if (!pstate->p_is_speculative)
+ {
+ InhOption = interpretInhOption(stmt->relation->inhOpt);
+
+ qry->specClause = SPEC_NONE;
+ }
+ else
+ {
+ /* auxiliary UPDATE does not accept ONLY */
+ InhOption = false;
+
+ qry->specClause = SPEC_UPDATE;
+ }
+
qry->resultRelation = setTargetTable(pstate, stmt->relation,
- interpretInhOption(stmt->relation->inhOpt),
+ InhOption,
true,
ACL_UPDATE);
qry->rtable = pstate->p_rtable;
qry->jointree = makeFromExpr(pstate->p_joinlist, qual);
+ qry->onConflict = NULL;
qry->hasSubLinks = pstate->p_hasSubLinks;
%type <list> cte_list
%type <list> within_group_clause
+%type <node> OnConflictUpdateStmt
%type <node> filter_clause
%type <list> window_clause window_definition_list opt_partition_clause
%type <windef> window_definition over_clause window_specification
;
opt_on_conflict:
+ ON CONFLICT opt_conf_expr OnConflictUpdateStmt
+ {
+ $$ = makeNode(ConflictClause);
+ $$->specclause = SPEC_INSERT;
+ $$->infer = $3;
+ $$->updatequery = $4;
+ $$->location = @1;
+ }
+ |
ON CONFLICT opt_conf_expr IGNORE_P
{
$$ = makeNode(ConflictClause);
$$->specclause = SPEC_IGNORE;
$$->infer = $3;
+ $$->updatequery = NULL;
$$->location = @1;
}
| /*EMPTY*/
}
;
+OnConflictUpdateStmt: UPDATE
+ SET set_clause_list
+ where_clause
+ {
+ UpdateStmt *n = makeNode(UpdateStmt);
+ /* NULL relation conveys auxiliary */
+ n->relation = NULL;
+ n->targetList = $3;
+ n->fromClause = NULL;
+ n->whereClause = $4;
+ n->returningList = NULL;
+ n->withClause = NULL;
+ $$ = (Node *)n;
+ }
+ ;
+
set_clause_list:
set_clause { $$ = $1; }
| set_clause_list ',' set_clause { $$ = list_concat($1,$3); }
* We also open the target relation and acquire a write lock on it.
* This must be done before processing the FROM list, in case the target
* is also mentioned as a source relation --- we want to be sure to grab
- * the write lock before any read lock.
+ * the write lock before any read lock. Note that when called during
+ * the parse analysis of an auxiliary UPDATE query, relation may be
+ * NULL, and the details are acquired from the parent.
*
* If alsoSource is true, add the target to the query's joinlist and
* namespace. For INSERT, we don't want the target to be joined to;
/*
* Open target rel and grab suitable lock (which we will hold till end of
- * transaction).
+ * transaction), iff this is not an auxiliary ON CONFLICT UPDATE.
*
* free_parsestate() will eventually do the corresponding heap_close(),
- * but *not* release the lock.
+ * but *not* release the lock (again, iff this is not an auxiliary ON
+ * CONFLICT UPDATE).
*/
- pstate->p_target_relation = parserOpenTable(pstate, relation,
- RowExclusiveLock);
+ if (!pstate->p_is_speculative || pstate->p_is_insert)
+ {
+ pstate->p_target_relation = parserOpenTable(pstate, relation,
+ RowExclusiveLock);
+
+ /*
+ * Now build an RTE.
+ */
+ rte = addRangeTableEntryForRelation(pstate, pstate->p_target_relation,
+ relation->alias, inh, false);
+
+ /*
+ * Override addRangeTableEntry's default ACL_SELECT permissions check,
+ * and instead mark target table as requiring exactly the specified
+ * permissions.
+ *
+ * If we find an explicit reference to the rel later during parse
+ * analysis, we will add the ACL_SELECT bit back again; see
+ * markVarForSelectPriv and its callers.
+ */
+ rte->requiredPerms = requiredPerms;
+ }
+ else
+ {
+ RangeTblEntry *exclRte;
+
+ /* Auxiliary UPDATE (of ON CONFLICT UPDATE) */
+ Assert(pstate->p_is_update);
+ /* Target shared with parent (INSERT) */
+ Assert(pstate->parentParseState->p_is_speculative);
+ Assert(pstate->parentParseState->p_is_insert);
+
+ pstate->p_target_relation =
+ pstate->parentParseState->p_target_relation;
+ rte = pstate->parentParseState->p_target_rangetblentry;
+
+ /*
+ * When called for auxiliary UPDATE, same target RTE is processed here
+ * for a second time. Just append requiredPerms. There is no need to
+ * override addRangeTableEntry's default ACL_SELECT permissions check
+ * now.
+ */
+ rte->requiredPerms |= requiredPerms;
+
+ /*
+ * Build EXCLUDED alias for target relation. This can be used to
+ * reference the tuple originally proposed for insertion from within
+ * the ON CONFLICT UPDATE auxiliary query. This is not visible in the
+ * parent INSERT.
+ *
+ * NOTE: 'EXCLUDED' will always have a varno equal to 1 (at least
+ * until rewriting, where the RTE is effectively discarded -- its Vars
+ * are replaced with a special-purpose primnode, ExcludedExpr).
+ */
+ exclRte = addRangeTableEntryForRelation(pstate,
+ pstate->p_target_relation,
+ makeAlias("excluded", NIL),
+ false, false);
+
+ /*
+ * Add EXCLUDED RTE to namespace. It does not matter that the RTE is
+ * not added to the Query joinlist, since its Vars are merely
+ * placeholders for ExcludedExpr.
+ */
+ addRTEtoQuery(pstate, exclRte, false, true, true);
+
+ /* Append parent/our target to Query rtable (should be last) */
+ pstate->p_rtable = lappend(pstate->p_rtable, rte);
+ }
- /*
- * Now build an RTE.
- */
- rte = addRangeTableEntryForRelation(pstate, pstate->p_target_relation,
- relation->alias, inh, false);
pstate->p_target_rangetblentry = rte;
/* assume new rte is at end */
rtindex = list_length(pstate->p_rtable);
Assert(rte == rt_fetch(rtindex, pstate->p_rtable));
- /*
- * Override addRangeTableEntry's default ACL_SELECT permissions check, and
- * instead mark target table as requiring exactly the specified
- * permissions.
- *
- * If we find an explicit reference to the rel later during parse
- * analysis, we will add the ACL_SELECT bit back again; see
- * markVarForSelectPriv and its callers.
- */
- rte->requiredPerms = requiredPerms;
-
/*
* If UPDATE/DELETE, add table to joinlist and namespace.
*
{
InferClause *infer = confClause->infer;
+ if (confClause->specclause == SPEC_INSERT && !infer)
+ ereport(ERROR,
+ (errcode(ERRCODE_SYNTAX_ERROR),
+ errmsg("ON CONFLICT with UPDATE must contain columns or expressions to infer a unique index from"),
+ parser_errposition(pstate,
+ exprLocation((Node *) confClause))));
+
+ Assert(confClause->specclause != SPEC_INSERT ||
+ confClause->updatequery != NULL);
+
/*
* To simplify certain aspects of its design, speculative insertion into
* system catalogs is disallowed
/*
* Check to see if the sublink is in an invalid place within the query. We
* allow sublinks everywhere in SELECT/INSERT/UPDATE/DELETE, but generally
- * not in utility statements.
+ * not in utility statements. They're also disallowed within auxiliary ON
+ * CONFLICT UPDATE commands, which we check for here.
*/
err = NULL;
switch (pstate->p_expr_kind)
* which is sane anyway.
*/
}
+
+ if (pstate->p_is_speculative && pstate->p_is_update)
+ err = _("cannot use subquery in ON CONFLICT UPDATE");
if (err)
ereport(ERROR,
(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
errmsg("target lists can have at most %d entries",
MaxTupleAttributeNumber)));
- if (pstate->p_target_relation != NULL)
+ /*
+ * Don't close target relation for auxiliary ON CONFLICT UPDATE, since it
+ * is managed by parent INSERT directly
+ */
+ if (pstate->p_target_relation != NULL &&
+ (!pstate->p_is_speculative ||
+ pstate->p_is_insert))
heap_close(pstate->p_target_relation, NoLock);
pfree(pstate);
bool for_execute; /* AcquireRewriteLocks' forExecute param */
} acquireLocksOnSubLinks_context;
+typedef struct excluded_replace_context
+{
+ int varno; /* varno of EXCLUDED.* Vars */
+ int rvarno; /* replace varno */
+} excluded_replace_context;
+
static bool acquireLocksOnSubLinks(Node *node,
acquireLocksOnSubLinks_context *context);
static Query *rewriteRuleAction(Query *parsetree,
bool forUpdatePushedDown);
static bool view_has_instead_trigger(Relation view, CmdType event);
static Bitmapset *adjust_view_column_set(Bitmapset *cols, List *targetlist);
+static Node *excluded_replace_vars(Node *expr,
+ excluded_replace_context * context);
+static Node *excluded_replace_vars_callback(Var *var,
+ replace_rte_variables_context *context);
/*
/* Process just the main targetlist */
rewriteTargetListIU(parsetree, rt_entry_relation, NULL);
}
+
+ if (parsetree->specClause == SPEC_INSERT)
+ {
+ Query *qry;
+ excluded_replace_context context;
+
+ /*
+ * While user-defined rules will never be applied in the
+ * auxiliary update query, normalization of tlist is still
+ * required
+ */
+ qry = (Query *) parsetree->onConflict;
+ rewriteTargetListIU(qry, rt_entry_relation, NULL);
+
+ /*
+ * Replace OLD Vars (associated with the EXCLUDED.* alias)
+ * with first (and only) "real" relation RTE in rtable. This
+ * allows the implementation to treat EXCLUDED.* as an alias
+ * for the target relation, which is useful during parse
+ * analysis, while ultimately having those references
+ * rewritten as special ExcludedExpr references to the
+ * corresponding Var in the target RTE.
+ *
+ * This is necessary because while we want a join-like syntax,
+ * the resemblance is superficial. This allows the optimizer
+ * to produce a simple sequential scan based auxiliary UPDATE
+ * plan, sufficient only for EvalPlanQaul() execution from the
+ * parent (a plan involving no actual join).
+ *
+ * This is a kludge, but appears necessary, since the slot
+ * made available for referencing via ExcludedExpr is in fact
+ * the slot just excluded from insertion by speculative
+ * insertion (with the effects of BEFORE ROW INSERT triggers
+ * carried). An ad-hoc method for making the EXCLUDED.* tuple
+ * available within the auxiliary expression context is
+ * appropriate -- the parent INSERT injects it immediately
+ * before auxiliary expression evaluation, because that is the
+ * only convenient time it is available. This seems far
+ * preferable to teaching the ModifyTable plans to behave like
+ * scan nodes (with rescanning required) just for the benefit
+ * of ON CONFLICT UPDATE.
+ */
+ context.varno = PRS2_OLD_VARNO;
+ context.rvarno = PRS2_NEW_VARNO;
+
+ parsetree->onConflict =
+ excluded_replace_vars(parsetree->onConflict, &context);
+ }
}
else if (event == CMD_UPDATE)
{
return results;
}
+
+/*
+ * Apply pullup variable replacement throughout an expression tree
+ *
+ * Returns modified tree, with user-specified rvarno replaced with varno.
+ */
+static Node *
+excluded_replace_vars(Node *expr, excluded_replace_context *context)
+{
+ /*
+ * Don't recurse into subqueries; they're forbidden in auxiliary ON
+ * CONFLICT query
+ */
+ return replace_rte_variables(expr,
+ context->varno, 0,
+ excluded_replace_vars_callback,
+ (void *) context,
+ NULL);
+}
+
+static Node *
+excluded_replace_vars_callback(Var *var,
+ replace_rte_variables_context *context)
+{
+ ExcludedExpr *n = makeNode(ExcludedExpr);
+ excluded_replace_context *rcon =
+ (excluded_replace_context *) context->callback_arg;
+
+ /* Replace with an enclosing ExcludedExpr */
+ var->varno = rcon->rvarno;
+ n->arg = (Node *) var;
+
+ /*
+ * Would have to adjust varlevelsup if referenced item is from higher
+ * query (should not happen)
+ */
+ Assert(var->varlevelsup == 0);
+
+ if (var->varattno < 0)
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_COLUMN_REFERENCE),
+ errmsg("cannot reference system column using EXCLUDED.* alias")));
+
+ if (var->varattno == 0)
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_COLUMN_REFERENCE),
+ errmsg("cannot reference whole-row using EXCLUDED.* alias")));
+
+ return (Node *) n;
+}
*/
if (completionTag)
{
- Oid lastOid;
+ Oid lastOid;
+ ModifyTableState *pstate;
switch (queryDesc->operation)
{
"SELECT %u", queryDesc->estate->es_processed);
break;
case CMD_INSERT:
+ pstate = (((ModifyTableState *) queryDesc->planstate));
+ Assert(IsA(pstate, ModifyTableState));
+
if (queryDesc->estate->es_processed == 1)
lastOid = queryDesc->estate->es_lastoid;
else
lastOid = InvalidOid;
snprintf(completionTag, COMPLETION_TAG_BUFSIZE,
- "INSERT %u %u", lastOid, queryDesc->estate->es_processed);
+ "%s %u %u", pstate->spec == SPEC_INSERT? "UPSERT":"INSERT",
+ lastOid, queryDesc->estate->es_processed);
break;
case CMD_UPDATE:
snprintf(completionTag, COMPLETION_TAG_BUFSIZE,
* 0" here because technically there is no query of the matching tag type,
* and printing a non-zero count for a different query type seems wrong,
* e.g. an INSERT that does an UPDATE instead should not print "0 1" if
- * one row was updated. See QueryRewrite(), step 3, for details.
+ * one row was updated (unless the ON CONFLICT UPDATE, or "UPSERT" variant
+ * of INSERT was used to update the row, where it's logically a direct
+ * effect of the top level command). See QueryRewrite(), step 3, for
+ * details.
*/
if (completionTag && completionTag[0] == '\0')
{
sprintf(completionTag, "SELECT 0 0");
else if (strcmp(completionTag, "INSERT") == 0)
strcpy(completionTag, "INSERT 0 0");
+ else if (strcmp(completionTag, "UPSERT") == 0)
+ strcpy(completionTag, "UPSERT 0 0");
else if (strcmp(completionTag, "UPDATE") == 0)
strcpy(completionTag, "UPDATE 0");
else if (strcmp(completionTag, "DELETE") == 0)
return NULL;
}
+ else if (var->varno == INNER_VAR)
+ {
+ /* Assume an EXCLUDED variable */
+ rte = rt_fetch(PRS2_OLD_VARNO, dpns->rtable);
+
+ /*
+ * Sanity check: EXCLUDED.* Vars should only appear in auxiliary ON
+ * CONFLICT UPDATE queries. Assert that rte and planstate are
+ * consistent with that.
+ */
+ Assert(rte->rtekind == RTE_RELATION);
+ Assert(IsA(dpns->planstate, SeqScanState) ||
+ IsA(dpns->planstate, ResultState));
+
+ refname = "excluded";
+ colinfo = deparse_columns_fetch(PRS2_OLD_VARNO, dpns);
+ attnum = var->varattno;
+ }
else
{
elog(ERROR, "bogus varno: %d", var->varno);
case T_CoerceToDomainValue:
case T_SetToDefault:
case T_CurrentOfExpr:
+ case T_ExcludedExpr:
/* single words: always simple */
return true;
}
break;
+ case T_ExcludedExpr:
+ {
+ ExcludedExpr *excludedexpr = (ExcludedExpr *) node;
+ Var *variable = (Var *) excludedexpr->arg;
+ bool save_varprefix;
+
+ /*
+ * Force parentheses because our caller probably assumed our
+ * Var is a simple expression.
+ */
+ appendStringInfoChar(buf, '(');
+ save_varprefix = context->varprefix;
+ /* Ensure EXCLUDED.* prefix is always visible */
+ context->varprefix = true;
+ get_rule_expr((Node *) variable, context, true);
+ context->varprefix = save_varprefix;
+ appendStringInfoChar(buf, ')');
+ }
+ break;
+
case T_List:
{
char *sep;
success = StoreQueryTuple(results);
else
success = PrintQueryTuples(results);
- /* if it's INSERT/UPDATE/DELETE RETURNING, also print status */
+ /*
+ * if it's INSERT/UPSERT/UPDATE/DELETE RETURNING, also print status
+ */
cmdstatus = PQcmdStatus(results);
if (strncmp(cmdstatus, "INSERT", 6) == 0 ||
+ strncmp(cmdstatus, "UPSERT", 6) == 0 ||
strncmp(cmdstatus, "UPDATE", 6) == 0 ||
strncmp(cmdstatus, "DELETE", 6) == 0)
PrintQueryStatus(results);
TupleTableSlot *slot, EState *estate);
extern void ExecWithCheckOptions(WCOKind kind, ResultRelInfo *resultRelInfo,
TupleTableSlot *slot, EState *estate);
+extern LockTupleMode ExecUpdateLockMode(EState *estate, ResultRelInfo *relinfo);
extern ExecRowMark *ExecFindRowMark(EState *estate, Index rti);
extern ExecAuxRowMark *ExecBuildAuxRowMark(ExecRowMark *erm, List *targetlist);
extern TupleTableSlot *EvalPlanQual(EState *estate, EPQState *epqstate,
ExprState *check_expr; /* for CHECK, a boolean expression */
} DomainConstraintState;
+/* ----------------
+ * ExcludedExprState node
+ * ----------------
+ */
+typedef struct ExcludedExprState
+{
+ ExprState xprstate;
+ ExprState *arg; /* the argument */
+} ExcludedExprState;
+
/* ----------------------------------------------------------------
* Executor State Trees
List **mt_arowmarks; /* per-subplan ExecAuxRowMark lists */
SpecCmd spec; /* reason for speculative insertion */
List *arbiterIndexes; /* unique index OIDs to arbitrate taking alt path */
+ PlanState *onConflict; /* associated OnConflict state */
EPQState mt_epqstate; /* for evaluating EvalPlanQual rechecks */
bool fireBSTriggers; /* do we need to fire stmt triggers? */
} ModifyTableState;
T_CoerceToDomainValue,
T_SetToDefault,
T_CurrentOfExpr,
+ T_ExcludedExpr,
T_InferenceElem,
T_TargetEntry,
T_RangeTblRef,
T_NullTestState,
T_CoerceToDomainState,
T_DomainConstraintState,
+ T_ExcludedExprState,
/*
* TAGS FOR PLANNER NODES (relation.h)
typedef enum
{
SPEC_NONE, /* Not involved in speculative insertion */
- SPEC_IGNORE /* INSERT of "ON CONFLICT IGNORE" */
+ SPEC_IGNORE, /* INSERT of "ON CONFLICT IGNORE" */
+ SPEC_INSERT, /* INSERT of "ON CONFLICT UPDATE" */
+ SPEC_UPDATE /* UPDATE of "ON CONFLICT UPDATE" */
} SpecCmd;
#endif /* NODES_H */
SpecCmd specClause; /* speculative insertion clause */
List *arbiterElems; /* unique index arbiter list (of InferenceElem's) */
Node *arbiterWhere; /* unique index arbiter WHERE clause */
+ Node *onConflict; /* ON CONFLICT Query */
List *returningList; /* return-values list (of TargetEntry) */
NodeTag type;
SpecCmd specclause; /* Variant specified */
InferClause *infer; /* Optional index inference clause */
+ Node *updatequery; /* Update parse stmt */
int location; /* token location, or -1 if unknown */
} ConflictClause;
typedef struct UpdateStmt
{
NodeTag type;
- RangeVar *relation; /* relation to update */
+ RangeVar *relation; /* relation to update (NULL for speculative) */
List *targetList; /* the target list (of ResTarget) */
Node *whereClause; /* qualifications */
List *fromClause; /* optional from clause for more tables */
List *plans; /* plan(s) producing source data */
SpecCmd spec; /* speculative insertion specification */
List *arbiterIndexes; /* List of ON CONFLICT arbiter index OIDs */
+ Plan *onConflictPlan; /* Plan for ON CONFLICT UPDATE auxiliary query */
List *withCheckOptionLists; /* per-target-table WCO lists */
List *returningLists; /* per-target-table RETURNING tlists */
List *fdwPrivLists; /* per-target-table FDW private data lists */
int cursor_param; /* refcursor parameter number, or 0 */
} CurrentOfExpr;
+/*
+ * ExcludedExpr - an EXCLUDED.* expression
+ *
+ * During parse analysis of ON CONFLICT UPDATE auxiliary queries, a dummy
+ * EXCLUDED range table entry is generated, which is actually just an alias for
+ * the target relation. This is useful during parse analysis, allowing the
+ * parser to produce simple error messages, for example. There is the
+ * appearance of a join within the auxiliary ON CONFLICT UPDATE, superficially
+ * similar to a join in an UPDATE ... FROM; this is a limited, ad-hoc join
+ * though, as the executor needs to tightly control the referenced tuple/slot
+ * through which update evaluation references excluded values originally
+ * proposed for insertion. Note that EXCLUDED.* values carry forward the
+ * effects of BEFORE ROW INSERT triggers.
+ *
+ * To implement a limited "join" for ON CONFLICT UPDATE auxiliary queries,
+ * during the rewrite stage, Vars referencing the alias EXCLUDED.* RTE are
+ * swapped with ExcludedExprs, which also contain Vars; their Vars are
+ * equivalent, but reference the target instead. The ExcludedExpr Var actually
+ * evaluates against varno INNER_VAR during expression evaluation (and not a
+ * varno INDEX_VAR associated with an entry in the flattened range table
+ * representing the target, which is necessarily being scanned whenever an
+ * ExcludedExpr is evaluated) while still being logically associated with the
+ * target. The Var is only rigged to reference the inner slot during
+ * ExcludedExpr initialization. The executor closely controls the evaluation
+ * expression, installing the EXCLUDED slot actually excluded from insertion
+ * into the inner slot of the child/auxiliary evaluation context in an ad-hoc
+ * fashion, which, after ExcludedExpr initialization, is expected (i.e. it is
+ * expected during ExcludedExpr evaluation that the parent insert will make
+ * each excluded tuple available in the inner slot in turn). ExcludedExpr are
+ * only ever evaluated during special speculative insertion related EPQ
+ * expression evaluation, purely for the benefit of auxiliary UPDATE
+ * expressions.
+ *
+ * Aside from representing a logical choke point for this special expression
+ * evaluation, having a dedicated primnode also prevents the optimizer from
+ * considering various optimization that might otherwise be attempted.
+ * Obviously there is no useful join optimization possible within the auxiliary
+ * query, and an ExcludedExpr based post-rewrite query tree representation is a
+ * convenient way of preventing that, as well as related inapplicable
+ * optimizations concerning the equivalence of Vars.
+ */
+typedef struct ExcludedExpr
+{
+ Expr xpr;
+ Node *arg; /* argument (Var) */
+} ExcludedExpr;
+
/*
* InferenceElem - an element of a unique index inference specification
*
Index nominalRelation,
List *resultRelations, List *subplans,
List *withCheckOptionLists, List *returningLists,
- List *rowMarks, SpecCmd spec, int epqParam);
+ List *rowMarks, Plan *onConflictPlan, SpecCmd spec,
+ int epqParam);
extern bool is_projection_capable_plan(Plan *plan);
/*
bool p_hasModifyingCTE;
bool p_is_insert;
bool p_is_update;
+ bool p_is_speculative;
bool p_locked_from_parent;
Relation p_target_relation;
RangeTblEntry *p_target_rangetblentry;
--- /dev/null
+Parsed test spec with 2 sessions
+
+starting permutation: insert1 insert2 c1 select2 c2
+step insert1: INSERT INTO upsert(key, payload) VALUES('FooFoo', 'insert1') ON CONFLICT (lower(key)) UPDATE set key = EXCLUDED.key, payload = TARGET.payload || ' updated by insert1';
+step insert2: INSERT INTO upsert(key, payload) VALUES('FOOFOO', 'insert2') ON CONFLICT (lower(key)) UPDATE set key = EXCLUDED.key, payload = TARGET.payload || ' updated by insert2'; <waiting ...>
+step c1: COMMIT;
+step insert2: <... completed>
+step select2: SELECT * FROM upsert;
+key payload
+
+FOOFOO insert1 updated by insert2
+step c2: COMMIT;
+
+starting permutation: insert1 insert2 a1 select2 c2
+step insert1: INSERT INTO upsert(key, payload) VALUES('FooFoo', 'insert1') ON CONFLICT (lower(key)) UPDATE set key = EXCLUDED.key, payload = TARGET.payload || ' updated by insert1';
+step insert2: INSERT INTO upsert(key, payload) VALUES('FOOFOO', 'insert2') ON CONFLICT (lower(key)) UPDATE set key = EXCLUDED.key, payload = TARGET.payload || ' updated by insert2'; <waiting ...>
+step a1: ABORT;
+step insert2: <... completed>
+step select2: SELECT * FROM upsert;
+key payload
+
+FOOFOO insert2
+step c2: COMMIT;
--- /dev/null
+Parsed test spec with 2 sessions
+
+starting permutation: update2 insert1 c2 select1surprise c1
+step update2: UPDATE colors SET is_active = true WHERE key = 1;
+step insert1:
+ WITH t AS (
+ INSERT INTO colors(key, color, is_active)
+ VALUES(1, 'Brown', true), (2, 'Gray', true)
+ ON CONFLICT (key) UPDATE
+ SET color = EXCLUDED.color
+ WHERE TARGET.is_active)
+ SELECT * FROM colors ORDER BY key; <waiting ...>
+step c2: COMMIT;
+step insert1: <... completed>
+key color is_active
+
+1 Red f
+2 Green f
+3 Blue f
+step select1surprise: SELECT * FROM colors ORDER BY key;
+key color is_active
+
+1 Brown t
+2 Green f
+3 Blue f
+step c1: COMMIT;
--- /dev/null
+Parsed test spec with 2 sessions
+
+starting permutation: insert1 insert2 c1 select2 c2
+step insert1: INSERT INTO upsert(key, val) VALUES(1, 'insert1') ON CONFLICT (key) UPDATE set val = TARGET.val || ' updated by insert1';
+step insert2: INSERT INTO upsert(key, val) VALUES(1, 'insert2') ON CONFLICT (key) UPDATE set val = TARGET.val || ' updated by insert2'; <waiting ...>
+step c1: COMMIT;
+step insert2: <... completed>
+step select2: SELECT * FROM upsert;
+key val
+
+1 insert1 updated by insert2
+step c2: COMMIT;
+
+starting permutation: insert1 insert2 a1 select2 c2
+step insert1: INSERT INTO upsert(key, val) VALUES(1, 'insert1') ON CONFLICT (key) UPDATE set val = TARGET.val || ' updated by insert1';
+step insert2: INSERT INTO upsert(key, val) VALUES(1, 'insert2') ON CONFLICT (key) UPDATE set val = TARGET.val || ' updated by insert2'; <waiting ...>
+step a1: ABORT;
+step insert2: <... completed>
+step select2: SELECT * FROM upsert;
+key val
+
+1 insert2
+step c2: COMMIT;
test: lock-update-delete
test: lock-update-traversal
test: insert-conflict-ignore
+test: insert-conflict-update
+test: insert-conflict-update-2
+test: insert-conflict-update-3
test: delete-abort-savept
test: delete-abort-savept-2
test: aborted-keyrevoke
--- /dev/null
+# INSERT...ON CONFLICT UPDATE test
+#
+# This test shows a plausible scenario in which the user might wish to UPDATE a
+# value that is also constrained by the unique index that is the arbiter of
+# whether the alternative path should be taken.
+
+setup
+{
+ CREATE TABLE upsert (key text not null, payload text);
+ CREATE UNIQUE INDEX ON upsert(lower(key));
+}
+
+teardown
+{
+ DROP TABLE upsert;
+}
+
+session "s1"
+setup
+{
+ BEGIN ISOLATION LEVEL READ COMMITTED;
+}
+step "insert1" { INSERT INTO upsert(key, payload) VALUES('FooFoo', 'insert1') ON CONFLICT (lower(key)) UPDATE set key = EXCLUDED.key, payload = TARGET.payload || ' updated by insert1'; }
+step "c1" { COMMIT; }
+step "a1" { ABORT; }
+
+session "s2"
+setup
+{
+ BEGIN ISOLATION LEVEL READ COMMITTED;
+}
+step "insert2" { INSERT INTO upsert(key, payload) VALUES('FOOFOO', 'insert2') ON CONFLICT (lower(key)) UPDATE set key = EXCLUDED.key, payload = TARGET.payload || ' updated by insert2'; }
+step "select2" { SELECT * FROM upsert; }
+step "c2" { COMMIT; }
+step "a2" { ABORT; }
+
+# One session (session 2) block-waits on another (session 1) to determine if it
+# should proceed with an insert or update. The user can still usefully UPDATE
+# a column constrained by a unique index, as the example illustrates.
+permutation "insert1" "insert2" "c1" "select2" "c2"
+permutation "insert1" "insert2" "a1" "select2" "c2"
--- /dev/null
+# INSERT...ON CONFLICT UPDATE test
+#
+# Other INSERT...ON CONFLICT UPDATE isolation tests illustrate the "MVCC
+# violation" added to facilitate the feature, whereby a
+# not-visible-to-our-snapshot tuple can be updated by our command all the same.
+# This is generally needed to provide a guarantee of a successful INSERT or
+# UPDATE in READ COMMITTED mode. This MVCC violation is quite distinct from
+# the putative "MVCC violation" that has existed in PostgreSQL for many years,
+# the EvalPlanQual() mechanism, because that mechanism always starts from a
+# tuple that is visible to the command's MVCC snapshot. This test illustrates
+# a slightly distinct user-visible consequence of the same MVCC violation
+# generally associated with INSERT...ON CONFLICT UPDATE. The impact of the
+# MVCC violation goes a little beyond updating MVCC-invisible tuples.
+#
+# With INSERT...ON CONFLICT UPDATE, the UPDATE predicate is only evaluated
+# once, on this conclusively-locked tuple, and not any other version of the
+# same tuple. It is therefore possible (in READ COMMITTED mode) that the
+# predicate "fail to be satisfied" according to the command's MVCC snapshot.
+# It might simply be that there is no row version visible, but it's also
+# possible that there is some row version visible, but only as a version that
+# doesn't satisfy the predicate. If, however, the conclusively-locked version
+# satisfies the predicate, that's good enough, and the tuple is updated. The
+# MVCC-snapshot-visible row version is denied the opportunity to prevent the
+# UPDATE from taking place, because we don't walk the UPDATE chain in the usual
+# way.
+
+setup
+{
+ CREATE TABLE colors (key int4 PRIMARY KEY, color text, is_active boolean);
+ INSERT INTO colors (key, color, is_active) VALUES(1, 'Red', false);
+ INSERT INTO colors (key, color, is_active) VALUES(2, 'Green', false);
+ INSERT INTO colors (key, color, is_active) VALUES(3, 'Blue', false);
+}
+
+teardown
+{
+ DROP TABLE colors;
+}
+
+session "s1"
+setup
+{
+ BEGIN ISOLATION LEVEL READ COMMITTED;
+}
+step "insert1" {
+ WITH t AS (
+ INSERT INTO colors(key, color, is_active)
+ VALUES(1, 'Brown', true), (2, 'Gray', true)
+ ON CONFLICT (key) UPDATE
+ SET color = EXCLUDED.color
+ WHERE TARGET.is_active)
+ SELECT * FROM colors ORDER BY key;}
+step "select1surprise" { SELECT * FROM colors ORDER BY key; }
+step "c1" { COMMIT; }
+
+session "s2"
+setup
+{
+ BEGIN ISOLATION LEVEL READ COMMITTED;
+}
+step "update2" { UPDATE colors SET is_active = true WHERE key = 1; }
+step "c2" { COMMIT; }
+
+# Perhaps surprisingly, the session 1 MVCC-snapshot-visible tuple (the tuple
+# with the pre-populated color 'Red') is denied the opportunity to prevent the
+# UPDATE from taking place -- only the conclusively-locked tuple version
+# matters, and so the tuple with key value 1 was updated to 'Brown' (but not
+# tuple with key value 2, since nothing changed there):
+permutation "update2" "insert1" "c2" "select1surprise" "c1"
--- /dev/null
+# INSERT...ON CONFLICT UPDATE test
+#
+# This test tries to expose problems with the interaction between concurrent
+# sessions.
+
+setup
+{
+ CREATE TABLE upsert (key int primary key, val text);
+}
+
+teardown
+{
+ DROP TABLE upsert;
+}
+
+session "s1"
+setup
+{
+ BEGIN ISOLATION LEVEL READ COMMITTED;
+}
+step "insert1" { INSERT INTO upsert(key, val) VALUES(1, 'insert1') ON CONFLICT (key) UPDATE set val = TARGET.val || ' updated by insert1'; }
+step "c1" { COMMIT; }
+step "a1" { ABORT; }
+
+session "s2"
+setup
+{
+ BEGIN ISOLATION LEVEL READ COMMITTED;
+}
+step "insert2" { INSERT INTO upsert(key, val) VALUES(1, 'insert2') ON CONFLICT (key) UPDATE set val = TARGET.val || ' updated by insert2'; }
+step "select2" { SELECT * FROM upsert; }
+step "c2" { COMMIT; }
+step "a2" { ABORT; }
+
+# One session (session 2) block-waits on another (session 1) to determine if it
+# should proceed with an insert or update. Notably, this entails updating a
+# tuple while there is no version of that tuple visible to the updating
+# session's snapshot. This is permitted only in READ COMMITTED mode.
+permutation "insert1" "insert2" "c1" "select2" "c2"
+permutation "insert1" "insert2" "a1" "select2" "c2"
drop index both_index_key;
drop index both_index_expr_key;
--
+-- Single key tests
+--
+create unique index key_index on insertconflicttest(key);
+--
+-- Explain tests
+--
+explain (costs off) insert into insertconflicttest values (0, 'Bilberry') on conflict (key) update set fruit = excluded.fruit;
+ QUERY PLAN
+----------------------------------------------------
+ Insert on insertconflicttest target
+ Conflict Arbiter Indexes: key_index
+ -> Result
+ -> Conflict Update on insertconflicttest target
+(4 rows)
+
+-- Should display qual actually attributable to internal sequential scan:
+explain (costs off) insert into insertconflicttest values (0, 'Bilberry') on conflict (key) update set fruit = excluded.fruit where target.fruit != 'Cawesh';
+ QUERY PLAN
+----------------------------------------------------
+ Insert on insertconflicttest target
+ Conflict Arbiter Indexes: key_index
+ -> Result
+ -> Conflict Update on insertconflicttest target
+ Filter: (fruit <> 'Cawesh'::text)
+(5 rows)
+
+-- With EXCLUDED.* expression in scan node:
+explain (costs off) insert into insertconflicttest values(0, 'Crowberry') on conflict (key) update set fruit = excluded.fruit where excluded.fruit != 'Elderberry';
+ QUERY PLAN
+----------------------------------------------------------
+ Insert on insertconflicttest target
+ Conflict Arbiter Indexes: key_index
+ -> Result
+ -> Conflict Update on insertconflicttest target
+ Filter: ((excluded.fruit) <> 'Elderberry'::text)
+(5 rows)
+
+-- Does the same, but JSON format shows "Conflict Arbiter Index" as JSON array:
+explain (costs off, format json) insert into insertconflicttest values (0, 'Bilberry') on conflict (key) update set fruit = excluded.fruit where target.fruit != 'Lime' returning *;
+ QUERY PLAN
+--------------------------------------------------
+ [ +
+ { +
+ "Plan": { +
+ "Node Type": "ModifyTable", +
+ "Operation": "Insert", +
+ "Relation Name": "insertconflicttest", +
+ "Alias": "target", +
+ "Conflict Arbiter Indexes": ["key_index"],+
+ "Plans": [ +
+ { +
+ "Node Type": "Result", +
+ "Parent Relationship": "Member" +
+ }, +
+ { +
+ "Node Type": "ModifyTable", +
+ "Operation": "Conflict Update", +
+ "Parent Relationship": "Member", +
+ "Relation Name": "insertconflicttest",+
+ "Alias": "target", +
+ "Filter": "(fruit <> 'Lime'::text)" +
+ } +
+ ] +
+ } +
+ } +
+ ]
+(1 row)
+
+-- Fails (no unique index inference specification, required for update variant):
+insert into insertconflicttest values (1, 'Apple') on conflict update set fruit = excluded.fruit;
+ERROR: ON CONFLICT with UPDATE must contain columns or expressions to infer a unique index from
+LINE 1: ...nsert into insertconflicttest values (1, 'Apple') on conflic...
+ ^
+-- inference succeeds:
+insert into insertconflicttest values (1, 'Apple') on conflict (key) update set fruit = excluded.fruit;
+insert into insertconflicttest values (2, 'Orange') on conflict (key, key, key) update set fruit = excluded.fruit;
+-- Succeed, since multi-assignment does not involve subquery:
+INSERT INTO insertconflicttest
+VALUES (1, 'Apple'), (2, 'Orange')
+ON CONFLICT (key) UPDATE SET (fruit, key) = (EXCLUDED.fruit, EXCLUDED.key);
+-- Don't accept original table name -- only TARGET.* alias:
+insert into insertconflicttest values (1, 'Apple') on conflict (key) update set fruit = insertconflicttest.fruit;
+ERROR: invalid reference to FROM-clause entry for table "insertconflicttest"
+LINE 1: ...(1, 'Apple') on conflict (key) update set fruit = insertconf...
+ ^
+HINT: Perhaps you meant to reference the table alias "excluded".
+-- inference fails:
+insert into insertconflicttest values (3, 'Kiwi') on conflict (key, fruit) update set fruit = excluded.fruit;
+ERROR: could not infer which unique index to use from expressions/columns and predicate provided for ON CONFLICT
+insert into insertconflicttest values (4, 'Mango') on conflict (fruit, key) update set fruit = excluded.fruit;
+ERROR: could not infer which unique index to use from expressions/columns and predicate provided for ON CONFLICT
+insert into insertconflicttest values (5, 'Lemon') on conflict (fruit) update set fruit = excluded.fruit;
+ERROR: could not infer which unique index to use from expressions/columns and predicate provided for ON CONFLICT
+insert into insertconflicttest values (6, 'Passionfruit') on conflict (lower(fruit)) update set fruit = excluded.fruit;
+ERROR: could not infer which unique index to use from expressions/columns and predicate provided for ON CONFLICT
+drop index key_index;
+--
+-- Composite key tests
+--
+create unique index comp_key_index on insertconflicttest(key, fruit);
+-- inference succeeds:
+insert into insertconflicttest values (7, 'Raspberry') on conflict (key, fruit) update set fruit = excluded.fruit;
+insert into insertconflicttest values (8, 'Lime') on conflict (fruit, key) update set fruit = excluded.fruit;
+-- inference fails:
+insert into insertconflicttest values (9, 'Banana') on conflict (key) update set fruit = excluded.fruit;
+ERROR: could not infer which unique index to use from expressions/columns and predicate provided for ON CONFLICT
+insert into insertconflicttest values (10, 'Blueberry') on conflict (key, key, key) update set fruit = excluded.fruit;
+ERROR: could not infer which unique index to use from expressions/columns and predicate provided for ON CONFLICT
+insert into insertconflicttest values (11, 'Cherry') on conflict (key, lower(fruit)) update set fruit = excluded.fruit;
+ERROR: could not infer which unique index to use from expressions/columns and predicate provided for ON CONFLICT
+insert into insertconflicttest values (12, 'Date') on conflict (lower(fruit), key) update set fruit = excluded.fruit;
+ERROR: could not infer which unique index to use from expressions/columns and predicate provided for ON CONFLICT
+drop index comp_key_index;
+--
+-- Partial index tests, no inference predicate specificied
+--
+create unique index part_comp_key_index on insertconflicttest(key, fruit) where key < 5;
+create unique index expr_part_comp_key_index on insertconflicttest(key, lower(fruit)) where key < 5;
+-- inference fails:
+insert into insertconflicttest values (13, 'Grape') on conflict (key, fruit) update set fruit = excluded.fruit;
+ERROR: could not infer which unique index to use from expressions/columns and predicate provided for ON CONFLICT
+insert into insertconflicttest values (14, 'Raisin') on conflict (fruit, key) update set fruit = excluded.fruit;
+ERROR: could not infer which unique index to use from expressions/columns and predicate provided for ON CONFLICT
+insert into insertconflicttest values (15, 'Cranberry') on conflict (key) update set fruit = excluded.fruit;
+ERROR: could not infer which unique index to use from expressions/columns and predicate provided for ON CONFLICT
+insert into insertconflicttest values (16, 'Melon') on conflict (key, key, key) update set fruit = excluded.fruit;
+ERROR: could not infer which unique index to use from expressions/columns and predicate provided for ON CONFLICT
+insert into insertconflicttest values (17, 'Mulberry') on conflict (key, lower(fruit)) update set fruit = excluded.fruit;
+ERROR: could not infer which unique index to use from expressions/columns and predicate provided for ON CONFLICT
+insert into insertconflicttest values (18, 'Pineapple') on conflict (lower(fruit), key) update set fruit = excluded.fruit;
+ERROR: could not infer which unique index to use from expressions/columns and predicate provided for ON CONFLICT
+drop index part_comp_key_index;
+drop index expr_part_comp_key_index;
+--
+-- Expression index tests
+--
+create unique index expr_key_index on insertconflicttest(lower(fruit));
+-- inference succeeds:
+insert into insertconflicttest values (20, 'Quince') on conflict (lower(fruit)) update set fruit = excluded.fruit;
+insert into insertconflicttest values (21, 'Pomegranate') on conflict (lower(fruit), lower(fruit)) update set fruit = excluded.fruit;
+-- inference fails:
+insert into insertconflicttest values (22, 'Apricot') on conflict (upper(fruit)) update set fruit = excluded.fruit;
+ERROR: could not infer which unique index to use from expressions/columns and predicate provided for ON CONFLICT
+insert into insertconflicttest values (23, 'Blackberry') on conflict (fruit) update set fruit = excluded.fruit;
+ERROR: could not infer which unique index to use from expressions/columns and predicate provided for ON CONFLICT
+drop index expr_key_index;
+--
+-- Expression index tests (with regular column)
+--
+create unique index expr_comp_key_index on insertconflicttest(key, lower(fruit));
+create unique index tricky_expr_comp_key_index on insertconflicttest(key, lower(fruit), upper(fruit));
+-- inference succeeds:
+insert into insertconflicttest values (24, 'Plum') on conflict (key, lower(fruit)) update set fruit = excluded.fruit;
+insert into insertconflicttest values (25, 'Peach') on conflict (lower(fruit), key) update set fruit = excluded.fruit;
+-- Should not infer "tricky_expr_comp_key_index" index:
+explain (costs off) insert into insertconflicttest values (26, 'Fig') on conflict (lower(fruit), key, lower(fruit), key) update set fruit = excluded.fruit;
+ QUERY PLAN
+----------------------------------------------------
+ Insert on insertconflicttest target
+ Conflict Arbiter Indexes: expr_comp_key_index
+ -> Result
+ -> Conflict Update on insertconflicttest target
+(4 rows)
+
+-- inference fails:
+insert into insertconflicttest values (27, 'Prune') on conflict (key, upper(fruit)) update set fruit = excluded.fruit;
+ERROR: could not infer which unique index to use from expressions/columns and predicate provided for ON CONFLICT
+insert into insertconflicttest values (28, 'Redcurrant') on conflict (fruit, key) update set fruit = excluded.fruit;
+ERROR: could not infer which unique index to use from expressions/columns and predicate provided for ON CONFLICT
+insert into insertconflicttest values (29, 'Nectarine') on conflict (key) update set fruit = excluded.fruit;
+ERROR: could not infer which unique index to use from expressions/columns and predicate provided for ON CONFLICT
+drop index expr_comp_key_index;
+drop index tricky_expr_comp_key_index;
+--
+-- Non-spurious duplicate violation tests
+--
+create unique index key_index on insertconflicttest(key);
+create unique index fruit_index on insertconflicttest(fruit);
+-- succeeds, since UPDATE happens to update "fruit" to existing value:
+insert into insertconflicttest values (26, 'Fig') on conflict (key) update set fruit = excluded.fruit;
+-- fails, since UPDATE is to row with key value 26, and we're updating "fruit"
+-- to a value that happens to exist in another row ('peach'):
+insert into insertconflicttest values (26, 'Peach') on conflict (key) update set fruit = excluded.fruit;
+ERROR: duplicate key value violates unique constraint "fruit_index"
+DETAIL: Key (fruit)=(Peach) already exists.
+-- succeeds, since "key" isn't repeated/referenced in UPDATE, and "fruit"
+-- arbitrates that statement updates existing "Fig" row:
+insert into insertconflicttest values (25, 'Fig') on conflict (fruit) update set fruit = excluded.fruit;
+drop index key_index;
+drop index fruit_index;
+--
-- Test partial unique index inference
--
create unique index partial_key_index on insertconflicttest(key) where fruit like '%berry';
-- Succeeds
+insert into insertconflicttest values (23, 'Blackberry') on conflict (key where fruit like '%berry') update set fruit = excluded.fruit;
insert into insertconflicttest values (23, 'Blackberry') on conflict (key where fruit like '%berry' and fruit = 'inconsequential') ignore;
-- fails
+insert into insertconflicttest values (23, 'Blackberry') on conflict (key) update set fruit = excluded.fruit;
+ERROR: could not infer which unique index to use from expressions/columns and predicate provided for ON CONFLICT
insert into insertconflicttest values (23, 'Blackberry') on conflict (key where fruit like '%berry' or fruit = 'consequential') ignore;
ERROR: could not infer which unique index to use from expressions/columns and predicate provided for ON CONFLICT
+insert into insertconflicttest values (23, 'Blackberry') on conflict (fruit where fruit like '%berry') update set fruit = excluded.fruit;
+ERROR: could not infer which unique index to use from expressions/columns and predicate provided for ON CONFLICT
insert into insertconflicttest values (23, 'Uncovered by Index') on conflict (key where fruit like '%berry') ignore;
ERROR: inferred arbiter partial unique index's predicate does not cover tuple proposed for insertion
DETAIL: ON CONFLICT inference clause implies that the tuple proposed for insertion must be covered by the predicate of partial index "partial_key_index".
-- Succeeds:
insert into cities values ('Las Vegas', 2.583E+5, 2174) on conflict ignore;
+insert into capitals values ('Sacramento', 4664.E+5, 30, 'CA') on conflict (name) update set population = excluded.population;
-- Wrong "Sacramento", ignored:
insert into capitals values ('Sacramento', 50, 2267, 'NE') on conflict (name) ignore;
select * from capitals;
name | population | altitude | state
------------+------------+----------+-------
- Sacramento | 369400 | 30 | CA
Madison | 191300 | 845 | WI
+ Sacramento | 466400000 | 30 | CA
(2 rows)
+insert into cities values ('Las Vegas', 5.83E+5, 2001) on conflict (name) update set population = excluded.population, altitude = excluded.altitude;
+select tableoid::regclass, * from cities;
+ tableoid | name | population | altitude
+----------+---------------+------------+----------
+ cities | San Francisco | 724000 | 63
+ cities | Mariposa | 1200 | 1953
+ cities | Las Vegas | 583000 | 2001
+ capitals | Madison | 191300 | 845
+ capitals | Sacramento | 466400000 | 30
+(5 rows)
+
+insert into capitals values ('Las Vegas', 5.83E+5, 2222, 'NV') on conflict (name) update set population = excluded.population;
+-- Capitals will contain new capital, Las Vegas:
+select * from capitals;
+ name | population | altitude | state
+------------+------------+----------+-------
+ Madison | 191300 | 845 | WI
+ Sacramento | 466400000 | 30 | CA
+ Las Vegas | 583000 | 2222 | NV
+(3 rows)
+
+-- Cities contains two instances of "Las Vegas", since unique constraints don't
+-- work across inheritance:
+select tableoid::regclass, * from cities;
+ tableoid | name | population | altitude
+----------+---------------+------------+----------
+ cities | San Francisco | 724000 | 63
+ cities | Mariposa | 1200 | 1953
+ cities | Las Vegas | 583000 | 2001
+ capitals | Madison | 191300 | 845
+ capitals | Sacramento | 466400000 | 30
+ capitals | Las Vegas | 583000 | 2222
+(6 rows)
+
+-- This only affects "cities" version of "Las Vegas":
+insert into cities values ('Las Vegas', 5.86E+5, 2223) on conflict (name) update set population = excluded.population, altitude = excluded.altitude;
+select tableoid::regclass, * from cities;
+ tableoid | name | population | altitude
+----------+---------------+------------+----------
+ cities | San Francisco | 724000 | 63
+ cities | Mariposa | 1200 | 1953
+ cities | Las Vegas | 586000 | 2223
+ capitals | Madison | 191300 | 845
+ capitals | Sacramento | 466400000 | 30
+ capitals | Las Vegas | 583000 | 2222
+(6 rows)
+
-- clean up
drop table capitals;
drop table cities;
ERROR: permission denied for relation atest2
-- Test column level permissions
SET SESSION AUTHORIZATION regressuser1;
-CREATE TABLE atest5 (one int, two int, three int);
+CREATE TABLE atest5 (one int, two int unique, three int);
CREATE TABLE atest6 (one int, two int, blue int);
GRANT SELECT (one), INSERT (two), UPDATE (three) ON atest5 TO regressuser4;
GRANT ALL (one) ON atest5 TO regressuser3;
ERROR: permission denied for relation atest5
UPDATE atest5 SET three = 5, one = 2; -- fail
ERROR: permission denied for relation atest5
+INSERT INTO atest5(two) VALUES (6) ON CONFLICT (two) UPDATE set three = 10; -- ok
+INSERT INTO atest5(two) VALUES (6) ON CONFLICT (two) UPDATE set one = 8; -- fails (due to UPDATE)
+ERROR: permission denied for relation atest5
+INSERT INTO atest5(three) VALUES (4) ON CONFLICT (two) UPDATE set three = 10; -- fails (due to INSERT)
+ERROR: permission denied for relation atest5
SET SESSION AUTHORIZATION regressuser1;
REVOKE ALL (one) ON atest5 FROM regressuser4;
GRANT SELECT (one,two,blue) ON atest6 TO regressuser4;
on conflict ignore;
ERROR: insert or update on table "rule_and_refint_t3" violates foreign key constraint "rule_and_refint_t3_id3a_fkey"
DETAIL: Key (id3a, id3b)=(1, 13) is not present in table "rule_and_refint_t1".
+-- rule not fired, so fk violation
+insert into rule_and_refint_t3 values (1, 13, 11, 'row6')
+ on conflict (id3a, id3b, id3c) update
+ set id3b = excluded.id3b;
+ERROR: insert or update on table "rule_and_refint_t3" violates foreign key constraint "rule_and_refint_t3_id3a_fkey"
+DETAIL: Key (id3a, id3b)=(1, 13) is not present in table "rule_and_refint_t1".
+-- rule fired, so unsupported
+insert into shoelace values ('sl9', 0, 'pink', 35.0, 'inch', 0.0)
+ on conflict (sl_name) update
+ set sl_avail = excluded.sl_avail;
+ERROR: INSERT with ON CONFLICT clause may not target relation with INSERT or UPDATE rules
create rule rule_and_refint_t3_ins as on insert to rule_and_refint_t3
where (exists (select 1 from rule_and_refint_t3
where (((rule_and_refint_t3.id3a = new.id3a)
-----
(0 rows)
+--
+-- Test case for subselect within UPDATE of INSERT...ON CONFLICT UPDATE
+--
+create temp table upsert(key int4 primary key, val text);
+insert into upsert values(1, 'val') on conflict (key) update set val = 'not seen';
+insert into upsert values(1, 'val') on conflict (key) update set val = 'unsupported ' || (select f1 from int4_tbl where f1 != 0 limit 1)::text;
+ERROR: cannot use subquery in ON CONFLICT UPDATE
+LINE 1: ...conflict (key) update set val = 'unsupported ' || (select f1...
+ ^
+select * from upsert;
+ key | val
+-----+-----
+ 1 | val
+(1 row)
+
+with aa as (select 'int4_tbl' u from int4_tbl limit 1)
+insert into upsert values (1, 'x'), (999, 'y')
+on conflict (key) update set val = (select u from aa)
+returning *;
+ERROR: cannot use subquery in ON CONFLICT UPDATE
+LINE 3: on conflict (key) update set val = (select u from aa)
+ ^
--
-- Test case for cross-type partial matching in hashed subplan (bug #7597)
--
-- tests for per-statement triggers
--
CREATE TABLE log_table (tstamp timestamp default timeofday()::timestamp);
-CREATE TABLE main_table (a int, b int);
+CREATE TABLE main_table (a int unique, b int);
COPY main_table (a,b) FROM stdin;
CREATE FUNCTION trigger_func() RETURNS trigger LANGUAGE plpgsql AS '
BEGIN
--
CREATE TRIGGER after_upd_stmt_trig AFTER UPDATE ON main_table
EXECUTE PROCEDURE trigger_func('after_upd_stmt');
+-- Both insert and update statement level triggers (before and after) should
+-- fire. Doesn't fire UPDATE before trigger, but only because one isn't
+-- defined.
+INSERT INTO main_table (a, b) VALUES (5, 10) ON CONFLICT (a)
+ UPDATE SET b = EXCLUDED.b;
+NOTICE: trigger_func(before_ins_stmt) called: action = INSERT, when = BEFORE, level = STATEMENT
+NOTICE: trigger_func(after_upd_stmt) called: action = UPDATE, when = AFTER, level = STATEMENT
+NOTICE: trigger_func(after_ins_stmt) called: action = INSERT, when = AFTER, level = STATEMENT
CREATE TRIGGER after_upd_row_trig AFTER UPDATE ON main_table
FOR EACH ROW EXECUTE PROCEDURE trigger_func('after_upd_row');
INSERT INTO main_table DEFAULT VALUES;
-- UPDATE that effects zero rows should still call per-statement trigger
UPDATE main_table SET a = a + 2 WHERE b > 100;
NOTICE: trigger_func(after_upd_stmt) called: action = UPDATE, when = AFTER, level = STATEMENT
+-- constraint now unneeded
+ALTER TABLE main_table DROP CONSTRAINT main_table_a_key;
-- COPY should fire per-row and per-statement INSERT triggers
COPY main_table (a, b) FROM stdin;
NOTICE: trigger_func(before_ins_stmt) called: action = INSERT, when = BEFORE, level = STATEMENT
drop table self_ref_trigger;
drop function self_ref_trigger_ins_func();
drop function self_ref_trigger_del_func();
+--
+-- Verify behavior of before and after triggers with INSERT...ON CONFLICT
+-- UPDATE
+--
+create table upsert (key int4 primary key, color text);
+create function upsert_before_func()
+ returns trigger language plpgsql as
+$$
+begin
+ if (TG_OP = 'UPDATE') then
+ raise warning 'before update (old): %', old.*::text;
+ raise warning 'before update (new): %', new.*::text;
+ elsif (TG_OP = 'INSERT') then
+ raise warning 'before insert (new): %', new.*::text;
+ if new.key % 2 = 0 then
+ new.key := new.key + 1;
+ new.color := new.color || ' trig modified';
+ raise warning 'before insert (new, modified): %', new.*::text;
+ end if;
+ end if;
+ return new;
+end;
+$$;
+create trigger upsert_before_trig before insert or update on upsert
+ for each row execute procedure upsert_before_func();
+create function upsert_after_func()
+ returns trigger language plpgsql as
+$$
+begin
+ if (TG_OP = 'UPDATE') then
+ raise warning 'after update (old): %', new.*::text;
+ raise warning 'after update (new): %', new.*::text;
+ elsif (TG_OP = 'INSERT') then
+ raise warning 'after insert (new): %', new.*::text;
+ end if;
+ return null;
+end;
+$$;
+create trigger upsert_after_trig after insert or update on upsert
+ for each row execute procedure upsert_after_func();
+insert into upsert values(1, 'black') on conflict (key) update set color = 'updated ' || target.color;
+WARNING: before insert (new): (1,black)
+WARNING: after insert (new): (1,black)
+insert into upsert values(2, 'red') on conflict (key) update set color = 'updated ' || target.color;
+WARNING: before insert (new): (2,red)
+WARNING: before insert (new, modified): (3,"red trig modified")
+WARNING: after insert (new): (3,"red trig modified")
+insert into upsert values(3, 'orange') on conflict (key) update set color = 'updated ' || target.color;
+WARNING: before insert (new): (3,orange)
+WARNING: before update (old): (3,"red trig modified")
+WARNING: before update (new): (3,"updated red trig modified")
+WARNING: after update (old): (3,"updated red trig modified")
+WARNING: after update (new): (3,"updated red trig modified")
+insert into upsert values(4, 'green') on conflict (key) update set color = 'updated ' || target.color;
+WARNING: before insert (new): (4,green)
+WARNING: before insert (new, modified): (5,"green trig modified")
+WARNING: after insert (new): (5,"green trig modified")
+insert into upsert values(5, 'purple') on conflict (key) update set color = 'updated ' || target.color;
+WARNING: before insert (new): (5,purple)
+WARNING: before update (old): (5,"green trig modified")
+WARNING: before update (new): (5,"updated green trig modified")
+WARNING: after update (old): (5,"updated green trig modified")
+WARNING: after update (new): (5,"updated green trig modified")
+insert into upsert values(6, 'white') on conflict (key) update set color = 'updated ' || target.color;
+WARNING: before insert (new): (6,white)
+WARNING: before insert (new, modified): (7,"white trig modified")
+WARNING: after insert (new): (7,"white trig modified")
+insert into upsert values(7, 'pink') on conflict (key) update set color = 'updated ' || target.color;
+WARNING: before insert (new): (7,pink)
+WARNING: before update (old): (7,"white trig modified")
+WARNING: before update (new): (7,"updated white trig modified")
+WARNING: after update (old): (7,"updated white trig modified")
+WARNING: after update (new): (7,"updated white trig modified")
+insert into upsert values(8, 'yellow') on conflict (key) update set color = 'updated ' || target.color;
+WARNING: before insert (new): (8,yellow)
+WARNING: before insert (new, modified): (9,"yellow trig modified")
+WARNING: after insert (new): (9,"yellow trig modified")
+select * from upsert;
+ key | color
+-----+-----------------------------
+ 1 | black
+ 3 | updated red trig modified
+ 5 | updated green trig modified
+ 7 | updated white trig modified
+ 9 | yellow trig modified
+(5 rows)
+
+drop table upsert;
+drop function upsert_before_func();
+drop function upsert_after_func();
INSERT INTO rw_view15 (a) VALUES (3); -- should be OK
INSERT INTO rw_view15 (a) VALUES (3) ON CONFLICT IGNORE; -- succeeds
INSERT INTO rw_view15 (a) VALUES (3) ON CONFLICT (a) IGNORE; -- succeeds
+INSERT INTO rw_view15 (a) VALUES (3) ON CONFLICT (a) UPDATE set a = excluded.a; -- fails (unsupported)
+ERROR: cannot insert into view "rw_view15"
+HINT: To enable inserting into the view, provide an INSTEAD OF INSERT trigger or an unconditional ON INSERT DO INSTEAD rule.
ALTER VIEW rw_view15 ALTER COLUMN upper SET DEFAULT 'NOT SET';
INSERT INTO rw_view15 (a) VALUES (4); -- should fail
ERROR: cannot insert into column "upper" of view "rw_view15"
42 | 12 | 10000
(4 rows)
+ALTER TABLE update_test ADD constraint uuu UNIQUE(a);
+-- fail, update predicates are disallowed:
+INSERT INTO update_test VALUES(31, 77) ON CONFLICT (a) UPDATE SET b = 16
+WHERE a NOT IN (SELECT a FROM update_test);
+ERROR: cannot use subquery in ON CONFLICT UPDATE
+LINE 2: WHERE a NOT IN (SELECT a FROM update_test);
+ ^
+INSERT INTO update_test VALUES(31, 77) ON CONFLICT (a) UPDATE SET b = 16
+WHERE EXISTS(SELECT b FROM update_test);
+ERROR: cannot use subquery in ON CONFLICT UPDATE
+LINE 2: WHERE EXISTS(SELECT b FROM update_test);
+ ^
+INSERT INTO update_test VALUES(31, 77) ON CONFLICT (a) UPDATE SET b = 16
+WHERE a IN (SELECT a FROM update_test);
+ERROR: cannot use subquery in ON CONFLICT UPDATE
+LINE 2: WHERE a IN (SELECT a FROM update_test);
+ ^
+INSERT INTO update_test VALUES(31, 77) ON CONFLICT (a) UPDATE SET b = 16
+WHERE a = ALL(SELECT a FROM update_test);
+ERROR: cannot use subquery in ON CONFLICT UPDATE
+LINE 2: WHERE a = ALL(SELECT a FROM update_test);
+ ^
+INSERT INTO update_test VALUES(31, 77) ON CONFLICT (a) UPDATE SET b = 16
+WHERE a = ANY(SELECT a FROM update_test);
+ERROR: cannot use subquery in ON CONFLICT UPDATE
+LINE 2: WHERE a = ANY(SELECT a FROM update_test);
+ ^
DROP TABLE update_test;
-400
(22 rows)
+-- data-modifying WITH containing INSERT...ON CONFLICT UPDATE
+CREATE TABLE z AS SELECT i AS k, (i || ' v')::text v FROM generate_series(1, 16, 3) i;
+ALTER TABLE z ADD UNIQUE (k);
+WITH t AS (
+ INSERT INTO z SELECT i, 'insert'
+ FROM generate_series(0, 16) i
+ ON CONFLICT (k) UPDATE SET v = TARGET.v || ', now update'
+ RETURNING *
+)
+SELECT * FROM t JOIN y ON t.k = y.a ORDER BY a, k;
+ k | v | a
+---+--------+---
+ 0 | insert | 0
+ 0 | insert | 0
+(2 rows)
+
+-- New query/snapshot demonstrates side-effects of previous query.
+SELECT * FROM z ORDER BY k;
+ k | v
+----+------------------
+ 0 | insert
+ 1 | 1 v, now update
+ 2 | insert
+ 3 | insert
+ 4 | 4 v, now update
+ 5 | insert
+ 6 | insert
+ 7 | 7 v, now update
+ 8 | insert
+ 9 | insert
+ 10 | 10 v, now update
+ 11 | insert
+ 12 | insert
+ 13 | 13 v, now update
+ 14 | insert
+ 15 | insert
+ 16 | 16 v, now update
+(17 rows)
+
+--
+-- All these cases should fail, due to restrictions imposed upon the UPDATE
+-- portion of the query.
+--
+WITH aa AS (SELECT 1 a, 2 b)
+INSERT INTO z VALUES(1, 'insert')
+ON CONFLICT (k) UPDATE SET v = (SELECT b || ' update' FROM aa WHERE a = 1 LIMIT 1);
+ERROR: cannot use subquery in ON CONFLICT UPDATE
+LINE 3: ON CONFLICT (k) UPDATE SET v = (SELECT b || ' update' FROM a...
+ ^
+WITH aa AS (SELECT 1 a, 2 b)
+INSERT INTO z VALUES(1, 'insert')
+ON CONFLICT (k) UPDATE SET v = ' update' WHERE target.k = (SELECT a FROM aa);
+ERROR: cannot use subquery in ON CONFLICT UPDATE
+LINE 3: ...ICT (k) UPDATE SET v = ' update' WHERE target.k = (SELECT a ...
+ ^
+WITH aa AS (SELECT 1 a, 2 b)
+INSERT INTO z VALUES(1, 'insert')
+ON CONFLICT (k) UPDATE SET v = (SELECT b || ' update' FROM aa WHERE a = 1 LIMIT 1);
+ERROR: cannot use subquery in ON CONFLICT UPDATE
+LINE 3: ON CONFLICT (k) UPDATE SET v = (SELECT b || ' update' FROM a...
+ ^
+WITH aa AS (SELECT 'a' a, 'b' b UNION ALL SELECT 'a' a, 'b' b)
+INSERT INTO z VALUES(1, 'insert')
+ON CONFLICT (k) UPDATE SET v = (SELECT b || ' update' FROM aa WHERE a = 'a' LIMIT 1);
+ERROR: cannot use subquery in ON CONFLICT UPDATE
+LINE 3: ON CONFLICT (k) UPDATE SET v = (SELECT b || ' update' FROM a...
+ ^
+WITH aa AS (SELECT 1 a, 2 b)
+INSERT INTO z VALUES(1, (SELECT b || ' insert' FROM aa WHERE a = 1 ))
+ON CONFLICT (k) UPDATE SET v = (SELECT b || ' update' FROM aa WHERE a = 1 LIMIT 1);
+ERROR: cannot use subquery in ON CONFLICT UPDATE
+LINE 3: ON CONFLICT (k) UPDATE SET v = (SELECT b || ' update' FROM a...
+ ^
+DROP TABLE z;
-- check that run to completion happens in proper ordering
TRUNCATE TABLE y;
INSERT INTO y SELECT generate_series(1, 3);
INSERT INTO UNIQUE_TBL (t) VALUES ('six');
INSERT INTO UNIQUE_TBL (t) VALUES ('seven');
+INSERT INTO UNIQUE_TBL VALUES (5, 'five-upsert-insert') ON CONFLICT (i) UPDATE SET t = 'five-upsert-update';
+INSERT INTO UNIQUE_TBL VALUES (6, 'six-upsert-insert') ON CONFLICT (i) UPDATE SET t = 'six-upsert-update';
+-- should fail
+INSERT INTO UNIQUE_TBL VALUES (1, 'a'), (2, 'b'), (2, 'b') ON CONFLICT (i) UPDATE SET t = 'fails';
+
SELECT '' AS five, * FROM UNIQUE_TBL;
DROP TABLE UNIQUE_TBL;
INSERT INTO UNIQUE_TBL VALUES (5, 'one');
INSERT INTO UNIQUE_TBL (t) VALUES ('six');
INSERT INTO UNIQUE_TBL (t) VALUES ('seven');
+INSERT INTO UNIQUE_TBL VALUES (5, 'five-upsert-insert') ON CONFLICT (i) UPDATE SET t = 'five-upsert-update';
+INSERT INTO UNIQUE_TBL VALUES (6, 'six-upsert-insert') ON CONFLICT (i) UPDATE SET t = 'six-upsert-update';
+-- should fail
+INSERT INTO UNIQUE_TBL VALUES (1, 'a'), (2, 'b'), (2, 'b') ON CONFLICT (i) UPDATE SET t = 'fails';
+ERROR: ON CONFLICT UPDATE command could not lock/update self-inserted tuple
+HINT: Ensure that no rows proposed for insertion within the same command have duplicate constrained values.
SELECT '' AS five, * FROM UNIQUE_TBL;
- five | i | t
-------+---+-------
+ five | i | t
+------+---+--------------------
| 1 | one
| 2 | two
| 4 | four
- | 5 | one
| | six
| | seven
-(6 rows)
+ | 5 | five-upsert-update
+ | 6 | six-upsert-insert
+(7 rows)
DROP TABLE UNIQUE_TBL;
CREATE TABLE UNIQUE_TBL (i int, t text,
drop index both_index_key;
drop index both_index_expr_key;
+--
+-- Single key tests
+--
+create unique index key_index on insertconflicttest(key);
+
+--
+-- Explain tests
+--
+explain (costs off) insert into insertconflicttest values (0, 'Bilberry') on conflict (key) update set fruit = excluded.fruit;
+-- Should display qual actually attributable to internal sequential scan:
+explain (costs off) insert into insertconflicttest values (0, 'Bilberry') on conflict (key) update set fruit = excluded.fruit where target.fruit != 'Cawesh';
+-- With EXCLUDED.* expression in scan node:
+explain (costs off) insert into insertconflicttest values(0, 'Crowberry') on conflict (key) update set fruit = excluded.fruit where excluded.fruit != 'Elderberry';
+-- Does the same, but JSON format shows "Conflict Arbiter Index" as JSON array:
+explain (costs off, format json) insert into insertconflicttest values (0, 'Bilberry') on conflict (key) update set fruit = excluded.fruit where target.fruit != 'Lime' returning *;
+
+-- Fails (no unique index inference specification, required for update variant):
+insert into insertconflicttest values (1, 'Apple') on conflict update set fruit = excluded.fruit;
+
+-- inference succeeds:
+insert into insertconflicttest values (1, 'Apple') on conflict (key) update set fruit = excluded.fruit;
+insert into insertconflicttest values (2, 'Orange') on conflict (key, key, key) update set fruit = excluded.fruit;
+
+-- Succeed, since multi-assignment does not involve subquery:
+INSERT INTO insertconflicttest
+VALUES (1, 'Apple'), (2, 'Orange')
+ON CONFLICT (key) UPDATE SET (fruit, key) = (EXCLUDED.fruit, EXCLUDED.key);
+-- Don't accept original table name -- only TARGET.* alias:
+insert into insertconflicttest values (1, 'Apple') on conflict (key) update set fruit = insertconflicttest.fruit;
+
+-- inference fails:
+insert into insertconflicttest values (3, 'Kiwi') on conflict (key, fruit) update set fruit = excluded.fruit;
+insert into insertconflicttest values (4, 'Mango') on conflict (fruit, key) update set fruit = excluded.fruit;
+insert into insertconflicttest values (5, 'Lemon') on conflict (fruit) update set fruit = excluded.fruit;
+insert into insertconflicttest values (6, 'Passionfruit') on conflict (lower(fruit)) update set fruit = excluded.fruit;
+
+drop index key_index;
+
+--
+-- Composite key tests
+--
+create unique index comp_key_index on insertconflicttest(key, fruit);
+
+-- inference succeeds:
+insert into insertconflicttest values (7, 'Raspberry') on conflict (key, fruit) update set fruit = excluded.fruit;
+insert into insertconflicttest values (8, 'Lime') on conflict (fruit, key) update set fruit = excluded.fruit;
+
+-- inference fails:
+insert into insertconflicttest values (9, 'Banana') on conflict (key) update set fruit = excluded.fruit;
+insert into insertconflicttest values (10, 'Blueberry') on conflict (key, key, key) update set fruit = excluded.fruit;
+insert into insertconflicttest values (11, 'Cherry') on conflict (key, lower(fruit)) update set fruit = excluded.fruit;
+insert into insertconflicttest values (12, 'Date') on conflict (lower(fruit), key) update set fruit = excluded.fruit;
+
+drop index comp_key_index;
+
+--
+-- Partial index tests, no inference predicate specificied
+--
+create unique index part_comp_key_index on insertconflicttest(key, fruit) where key < 5;
+create unique index expr_part_comp_key_index on insertconflicttest(key, lower(fruit)) where key < 5;
+
+-- inference fails:
+insert into insertconflicttest values (13, 'Grape') on conflict (key, fruit) update set fruit = excluded.fruit;
+insert into insertconflicttest values (14, 'Raisin') on conflict (fruit, key) update set fruit = excluded.fruit;
+insert into insertconflicttest values (15, 'Cranberry') on conflict (key) update set fruit = excluded.fruit;
+insert into insertconflicttest values (16, 'Melon') on conflict (key, key, key) update set fruit = excluded.fruit;
+insert into insertconflicttest values (17, 'Mulberry') on conflict (key, lower(fruit)) update set fruit = excluded.fruit;
+insert into insertconflicttest values (18, 'Pineapple') on conflict (lower(fruit), key) update set fruit = excluded.fruit;
+
+drop index part_comp_key_index;
+drop index expr_part_comp_key_index;
+
+--
+-- Expression index tests
+--
+create unique index expr_key_index on insertconflicttest(lower(fruit));
+
+-- inference succeeds:
+insert into insertconflicttest values (20, 'Quince') on conflict (lower(fruit)) update set fruit = excluded.fruit;
+insert into insertconflicttest values (21, 'Pomegranate') on conflict (lower(fruit), lower(fruit)) update set fruit = excluded.fruit;
+
+-- inference fails:
+insert into insertconflicttest values (22, 'Apricot') on conflict (upper(fruit)) update set fruit = excluded.fruit;
+insert into insertconflicttest values (23, 'Blackberry') on conflict (fruit) update set fruit = excluded.fruit;
+
+drop index expr_key_index;
+
+--
+-- Expression index tests (with regular column)
+--
+create unique index expr_comp_key_index on insertconflicttest(key, lower(fruit));
+create unique index tricky_expr_comp_key_index on insertconflicttest(key, lower(fruit), upper(fruit));
+
+-- inference succeeds:
+insert into insertconflicttest values (24, 'Plum') on conflict (key, lower(fruit)) update set fruit = excluded.fruit;
+insert into insertconflicttest values (25, 'Peach') on conflict (lower(fruit), key) update set fruit = excluded.fruit;
+-- Should not infer "tricky_expr_comp_key_index" index:
+explain (costs off) insert into insertconflicttest values (26, 'Fig') on conflict (lower(fruit), key, lower(fruit), key) update set fruit = excluded.fruit;
+
+-- inference fails:
+insert into insertconflicttest values (27, 'Prune') on conflict (key, upper(fruit)) update set fruit = excluded.fruit;
+insert into insertconflicttest values (28, 'Redcurrant') on conflict (fruit, key) update set fruit = excluded.fruit;
+insert into insertconflicttest values (29, 'Nectarine') on conflict (key) update set fruit = excluded.fruit;
+
+drop index expr_comp_key_index;
+drop index tricky_expr_comp_key_index;
+
+--
+-- Non-spurious duplicate violation tests
+--
+create unique index key_index on insertconflicttest(key);
+create unique index fruit_index on insertconflicttest(fruit);
+
+-- succeeds, since UPDATE happens to update "fruit" to existing value:
+insert into insertconflicttest values (26, 'Fig') on conflict (key) update set fruit = excluded.fruit;
+-- fails, since UPDATE is to row with key value 26, and we're updating "fruit"
+-- to a value that happens to exist in another row ('peach'):
+insert into insertconflicttest values (26, 'Peach') on conflict (key) update set fruit = excluded.fruit;
+-- succeeds, since "key" isn't repeated/referenced in UPDATE, and "fruit"
+-- arbitrates that statement updates existing "Fig" row:
+insert into insertconflicttest values (25, 'Fig') on conflict (fruit) update set fruit = excluded.fruit;
+
+drop index key_index;
+drop index fruit_index;
+
--
-- Test partial unique index inference
--
create unique index partial_key_index on insertconflicttest(key) where fruit like '%berry';
-- Succeeds
+insert into insertconflicttest values (23, 'Blackberry') on conflict (key where fruit like '%berry') update set fruit = excluded.fruit;
insert into insertconflicttest values (23, 'Blackberry') on conflict (key where fruit like '%berry' and fruit = 'inconsequential') ignore;
-- fails
+insert into insertconflicttest values (23, 'Blackberry') on conflict (key) update set fruit = excluded.fruit;
insert into insertconflicttest values (23, 'Blackberry') on conflict (key where fruit like '%berry' or fruit = 'consequential') ignore;
+insert into insertconflicttest values (23, 'Blackberry') on conflict (fruit where fruit like '%berry') update set fruit = excluded.fruit;
insert into insertconflicttest values (23, 'Uncovered by Index') on conflict (key where fruit like '%berry') ignore;
drop index partial_key_index;
-- Succeeds:
insert into cities values ('Las Vegas', 2.583E+5, 2174) on conflict ignore;
+insert into capitals values ('Sacramento', 4664.E+5, 30, 'CA') on conflict (name) update set population = excluded.population;
-- Wrong "Sacramento", ignored:
insert into capitals values ('Sacramento', 50, 2267, 'NE') on conflict (name) ignore;
select * from capitals;
+insert into cities values ('Las Vegas', 5.83E+5, 2001) on conflict (name) update set population = excluded.population, altitude = excluded.altitude;
+select tableoid::regclass, * from cities;
+insert into capitals values ('Las Vegas', 5.83E+5, 2222, 'NV') on conflict (name) update set population = excluded.population;
+-- Capitals will contain new capital, Las Vegas:
+select * from capitals;
+-- Cities contains two instances of "Las Vegas", since unique constraints don't
+-- work across inheritance:
+select tableoid::regclass, * from cities;
+-- This only affects "cities" version of "Las Vegas":
+insert into cities values ('Las Vegas', 5.86E+5, 2223) on conflict (name) update set population = excluded.population, altitude = excluded.altitude;
+select tableoid::regclass, * from cities;
+
-- clean up
drop table capitals;
-- Test column level permissions
SET SESSION AUTHORIZATION regressuser1;
-CREATE TABLE atest5 (one int, two int, three int);
+CREATE TABLE atest5 (one int, two int unique, three int);
CREATE TABLE atest6 (one int, two int, blue int);
GRANT SELECT (one), INSERT (two), UPDATE (three) ON atest5 TO regressuser4;
GRANT ALL (one) ON atest5 TO regressuser3;
UPDATE atest5 SET three = 10; -- ok
UPDATE atest5 SET one = 8; -- fail
UPDATE atest5 SET three = 5, one = 2; -- fail
+INSERT INTO atest5(two) VALUES (6) ON CONFLICT (two) UPDATE set three = 10; -- ok
+INSERT INTO atest5(two) VALUES (6) ON CONFLICT (two) UPDATE set one = 8; -- fails (due to UPDATE)
+INSERT INTO atest5(three) VALUES (4) ON CONFLICT (two) UPDATE set three = 10; -- fails (due to INSERT)
SET SESSION AUTHORIZATION regressuser1;
REVOKE ALL (one) ON atest5 FROM regressuser4;
-- Ordinary table
insert into rule_and_refint_t3 values (1, 13, 11, 'row6')
on conflict ignore;
+-- rule not fired, so fk violation
+insert into rule_and_refint_t3 values (1, 13, 11, 'row6')
+ on conflict (id3a, id3b, id3c) update
+ set id3b = excluded.id3b;
+-- rule fired, so unsupported
+insert into shoelace values ('sl9', 0, 'pink', 35.0, 'inch', 0.0)
+ on conflict (sl_name) update
+ set sl_avail = excluded.sl_avail;
create rule rule_and_refint_t3_ins as on insert to rule_and_refint_t3
where (exists (select 1 from rule_and_refint_t3
join
int4_tbl i4 on dummy = i4.f1;
+--
+-- Test case for subselect within UPDATE of INSERT...ON CONFLICT UPDATE
+--
+create temp table upsert(key int4 primary key, val text);
+insert into upsert values(1, 'val') on conflict (key) update set val = 'not seen';
+insert into upsert values(1, 'val') on conflict (key) update set val = 'unsupported ' || (select f1 from int4_tbl where f1 != 0 limit 1)::text;
+
+select * from upsert;
+
+with aa as (select 'int4_tbl' u from int4_tbl limit 1)
+insert into upsert values (1, 'x'), (999, 'y')
+on conflict (key) update set val = (select u from aa)
+returning *;
+
--
-- Test case for cross-type partial matching in hashed subplan (bug #7597)
--
CREATE TABLE log_table (tstamp timestamp default timeofday()::timestamp);
-CREATE TABLE main_table (a int, b int);
+CREATE TABLE main_table (a int unique, b int);
COPY main_table (a,b) FROM stdin;
5 10
CREATE TRIGGER after_upd_stmt_trig AFTER UPDATE ON main_table
EXECUTE PROCEDURE trigger_func('after_upd_stmt');
+-- Both insert and update statement level triggers (before and after) should
+-- fire. Doesn't fire UPDATE before trigger, but only because one isn't
+-- defined.
+INSERT INTO main_table (a, b) VALUES (5, 10) ON CONFLICT (a)
+ UPDATE SET b = EXCLUDED.b;
+
CREATE TRIGGER after_upd_row_trig AFTER UPDATE ON main_table
FOR EACH ROW EXECUTE PROCEDURE trigger_func('after_upd_row');
-- UPDATE that effects zero rows should still call per-statement trigger
UPDATE main_table SET a = a + 2 WHERE b > 100;
+-- constraint now unneeded
+ALTER TABLE main_table DROP CONSTRAINT main_table_a_key;
+
-- COPY should fire per-row and per-statement INSERT triggers
COPY main_table (a, b) FROM stdin;
30 40
drop table self_ref_trigger;
drop function self_ref_trigger_ins_func();
drop function self_ref_trigger_del_func();
+
+--
+-- Verify behavior of before and after triggers with INSERT...ON CONFLICT
+-- UPDATE
+--
+create table upsert (key int4 primary key, color text);
+
+create function upsert_before_func()
+ returns trigger language plpgsql as
+$$
+begin
+ if (TG_OP = 'UPDATE') then
+ raise warning 'before update (old): %', old.*::text;
+ raise warning 'before update (new): %', new.*::text;
+ elsif (TG_OP = 'INSERT') then
+ raise warning 'before insert (new): %', new.*::text;
+ if new.key % 2 = 0 then
+ new.key := new.key + 1;
+ new.color := new.color || ' trig modified';
+ raise warning 'before insert (new, modified): %', new.*::text;
+ end if;
+ end if;
+ return new;
+end;
+$$;
+create trigger upsert_before_trig before insert or update on upsert
+ for each row execute procedure upsert_before_func();
+
+create function upsert_after_func()
+ returns trigger language plpgsql as
+$$
+begin
+ if (TG_OP = 'UPDATE') then
+ raise warning 'after update (old): %', new.*::text;
+ raise warning 'after update (new): %', new.*::text;
+ elsif (TG_OP = 'INSERT') then
+ raise warning 'after insert (new): %', new.*::text;
+ end if;
+ return null;
+end;
+$$;
+create trigger upsert_after_trig after insert or update on upsert
+ for each row execute procedure upsert_after_func();
+
+insert into upsert values(1, 'black') on conflict (key) update set color = 'updated ' || target.color;
+insert into upsert values(2, 'red') on conflict (key) update set color = 'updated ' || target.color;
+insert into upsert values(3, 'orange') on conflict (key) update set color = 'updated ' || target.color;
+insert into upsert values(4, 'green') on conflict (key) update set color = 'updated ' || target.color;
+insert into upsert values(5, 'purple') on conflict (key) update set color = 'updated ' || target.color;
+insert into upsert values(6, 'white') on conflict (key) update set color = 'updated ' || target.color;
+insert into upsert values(7, 'pink') on conflict (key) update set color = 'updated ' || target.color;
+insert into upsert values(8, 'yellow') on conflict (key) update set color = 'updated ' || target.color;
+
+select * from upsert;
+
+drop table upsert;
+drop function upsert_before_func();
+drop function upsert_after_func();
INSERT INTO rw_view15 (a) VALUES (3); -- should be OK
INSERT INTO rw_view15 (a) VALUES (3) ON CONFLICT IGNORE; -- succeeds
INSERT INTO rw_view15 (a) VALUES (3) ON CONFLICT (a) IGNORE; -- succeeds
+INSERT INTO rw_view15 (a) VALUES (3) ON CONFLICT (a) UPDATE set a = excluded.a; -- fails (unsupported)
ALTER VIEW rw_view15 ALTER COLUMN upper SET DEFAULT 'NOT SET';
INSERT INTO rw_view15 (a) VALUES (4); -- should fail
UPDATE rw_view15 SET upper='ROW 3' WHERE a=3; -- should fail
UPDATE update_test SET c = repeat('x', 10000) WHERE c = 'car';
SELECT a, b, char_length(c) FROM update_test;
+ALTER TABLE update_test ADD constraint uuu UNIQUE(a);
+
+-- fail, update predicates are disallowed:
+INSERT INTO update_test VALUES(31, 77) ON CONFLICT (a) UPDATE SET b = 16
+WHERE a NOT IN (SELECT a FROM update_test);
+INSERT INTO update_test VALUES(31, 77) ON CONFLICT (a) UPDATE SET b = 16
+WHERE EXISTS(SELECT b FROM update_test);
+INSERT INTO update_test VALUES(31, 77) ON CONFLICT (a) UPDATE SET b = 16
+WHERE a IN (SELECT a FROM update_test);
+INSERT INTO update_test VALUES(31, 77) ON CONFLICT (a) UPDATE SET b = 16
+WHERE a = ALL(SELECT a FROM update_test);
+INSERT INTO update_test VALUES(31, 77) ON CONFLICT (a) UPDATE SET b = 16
+WHERE a = ANY(SELECT a FROM update_test);
+
DROP TABLE update_test;
SELECT * FROM y;
+-- data-modifying WITH containing INSERT...ON CONFLICT UPDATE
+CREATE TABLE z AS SELECT i AS k, (i || ' v')::text v FROM generate_series(1, 16, 3) i;
+ALTER TABLE z ADD UNIQUE (k);
+
+WITH t AS (
+ INSERT INTO z SELECT i, 'insert'
+ FROM generate_series(0, 16) i
+ ON CONFLICT (k) UPDATE SET v = TARGET.v || ', now update'
+ RETURNING *
+)
+SELECT * FROM t JOIN y ON t.k = y.a ORDER BY a, k;
+
+-- New query/snapshot demonstrates side-effects of previous query.
+SELECT * FROM z ORDER BY k;
+
+--
+-- All these cases should fail, due to restrictions imposed upon the UPDATE
+-- portion of the query.
+--
+WITH aa AS (SELECT 1 a, 2 b)
+INSERT INTO z VALUES(1, 'insert')
+ON CONFLICT (k) UPDATE SET v = (SELECT b || ' update' FROM aa WHERE a = 1 LIMIT 1);
+WITH aa AS (SELECT 1 a, 2 b)
+INSERT INTO z VALUES(1, 'insert')
+ON CONFLICT (k) UPDATE SET v = ' update' WHERE target.k = (SELECT a FROM aa);
+WITH aa AS (SELECT 1 a, 2 b)
+INSERT INTO z VALUES(1, 'insert')
+ON CONFLICT (k) UPDATE SET v = (SELECT b || ' update' FROM aa WHERE a = 1 LIMIT 1);
+WITH aa AS (SELECT 'a' a, 'b' b UNION ALL SELECT 'a' a, 'b' b)
+INSERT INTO z VALUES(1, 'insert')
+ON CONFLICT (k) UPDATE SET v = (SELECT b || ' update' FROM aa WHERE a = 'a' LIMIT 1);
+WITH aa AS (SELECT 1 a, 2 b)
+INSERT INTO z VALUES(1, (SELECT b || ' insert' FROM aa WHERE a = 1 ))
+ON CONFLICT (k) UPDATE SET v = (SELECT b || ' update' FROM aa WHERE a = 1 LIMIT 1);
+
+DROP TABLE z;
+
-- check that run to completion happens in proper ordering
TRUNCATE TABLE y;