Improve ON CONFLICT documentation.

Author: Peter Geoghegan and Andres Freund
Discussion: CAM3SWZScpWzQ-7EJC77vwqzZ1GO8GNmURQ1QqDQ3wRn7AbW1Cg@mail.gmail.com
Backpatch: 9.5, where ON CONFLICT was introduced
This commit is contained in:
Andres Freund 2015-11-10 00:02:49 +01:00
parent 32f15d05c8
commit edf68b2ed5
1 changed files with 354 additions and 341 deletions

View File

@ -99,7 +99,8 @@ INSERT INTO <replaceable class="PARAMETER">table_name</replaceable> [ AS <replac
<para> <para>
You must have <literal>INSERT</literal> privilege on a table in You must have <literal>INSERT</literal> privilege on a table in
order to insert into it. If <literal>ON CONFLICT DO UPDATE</> is order to insert into it. If <literal>ON CONFLICT DO UPDATE</> is
present the <literal>UPDATE</literal> privilege is also required. present, <literal>UPDATE</literal> privilege on the table is also
required.
</para> </para>
<para> <para>
@ -126,6 +127,16 @@ INSERT INTO <replaceable class="PARAMETER">table_name</replaceable> [ AS <replac
<refsect1> <refsect1>
<title>Parameters</title> <title>Parameters</title>
<refsect2 id="SQL-INSERTING-PARAMS">
<title id="sql-inserting-params-title">Inserting</title>
<para>
This section covers parameters that may be used when only
inserting new rows. Parameters <emphasis>exclusively</emphasis>
used with the <literal>ON CONFLICT</literal> clause are described
separately.
</para>
<variablelist> <variablelist>
<varlistentry> <varlistentry>
<term><replaceable class="parameter">with_query</replaceable></term> <term><replaceable class="parameter">with_query</replaceable></term>
@ -160,11 +171,13 @@ INSERT INTO <replaceable class="PARAMETER">table_name</replaceable> [ AS <replac
<term><replaceable class="parameter">alias</replaceable></term> <term><replaceable class="parameter">alias</replaceable></term>
<listitem> <listitem>
<para> <para>
A substitute name for the target table. When an alias is provided, it A substitute name for <replaceable
completely hides the actual name of the table. This is particularly class="PARAMETER">table_name</replaceable>. When an alias is
useful when using <literal>ON CONFLICT DO UPDATE</literal> into a table provided, it completely hides the actual name of the table.
named <literal>excluded</literal> as that's also the name of the This is particularly useful when <literal>ON CONFLICT DO
pseudo-relation containing the proposed row. UPDATE</literal> targets a table named excluded, since that's
also the name of the special table representing rows proposed
for insertion.
</para> </para>
</listitem> </listitem>
</varlistentry> </varlistentry>
@ -174,14 +187,15 @@ INSERT INTO <replaceable class="PARAMETER">table_name</replaceable> [ AS <replac
<term><replaceable class="PARAMETER">column_name</replaceable></term> <term><replaceable class="PARAMETER">column_name</replaceable></term>
<listitem> <listitem>
<para> <para>
The name of a column in the table named by <replaceable class="PARAMETER">table_name</replaceable>. The name of a column in the table named by <replaceable
The column name can be qualified with a subfield name or array class="PARAMETER">table_name</replaceable>. The column name
subscript, if needed. (Inserting into only some fields of a can be qualified with a subfield name or array subscript, if
composite column leaves the other fields null.) When needed. (Inserting into only some fields of a composite
referencing a column with <literal>ON CONFLICT DO UPDATE</>, do column leaves the other fields null.) When referencing a
not include the table's name in the specification of a target column with <literal>ON CONFLICT DO UPDATE</>, do not include
column. For example, <literal>INSERT ... ON CONFLICT DO UPDATE the table's name in the specification of a target column. For
tab SET table_name.col = 1</> is invalid (this follows the general example, <literal>INSERT ... ON CONFLICT DO UPDATE tab SET
table_name.col = 1</> is invalid (this follows the general
behavior for <command>UPDATE</>). behavior for <command>UPDATE</>).
</para> </para>
</listitem> </listitem>
@ -231,31 +245,13 @@ INSERT INTO <replaceable class="PARAMETER">table_name</replaceable> [ AS <replac
<term><replaceable class="PARAMETER">output_expression</replaceable></term> <term><replaceable class="PARAMETER">output_expression</replaceable></term>
<listitem> <listitem>
<para> <para>
An expression to be computed and returned by the <command>INSERT</> An expression to be computed and returned by the
command after each row is inserted (not updated). The <command>INSERT</> command after each row is inserted or
expression can use any column names of the table named by updated. The expression can use any column names of the table
<replaceable class="PARAMETER">table_name</replaceable>. named by <replaceable
Write <literal>*</> to return all columns of the inserted row(s). class="PARAMETER">table_name</replaceable>. Write
</para> <literal>*</> to return all columns of the inserted or updated
</listitem> row(s).
</varlistentry>
<varlistentry>
<term><literal>conflict_target</literal></term>
<listitem>
<para>
Specify which conflicts <literal>ON CONFLICT</literal> refers to.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>conflict_action</literal></term>
<listitem>
<para>
<literal>DO NOTHING</literal> or <literal>DO UPDATE
SET</literal> clause specifying the action to be performed in
case of a conflict.
</para> </para>
</listitem> </listitem>
</varlistentry> </varlistentry>
@ -268,14 +264,114 @@ INSERT INTO <replaceable class="PARAMETER">table_name</replaceable> [ AS <replac
</para> </para>
</listitem> </listitem>
</varlistentry> </varlistentry>
</variablelist>
</refsect2>
<refsect2 id="sql-on-conflict">
<title id="sql-on-conflict-title"><literal>ON CONFLICT</literal> Clause</title>
<indexterm zone="SQL-INSERT">
<primary>UPSERT</primary>
</indexterm>
<indexterm zone="SQL-INSERT">
<primary>ON CONFLICT</primary>
</indexterm>
<para>
The optional <literal>ON CONFLICT</literal> clause specifies an
alternative action to raising a unique violation or exclusion
constraint violation error. For each individual row proposed for
insertion, either the insertion proceeds, or, if an
<emphasis>arbiter</emphasis> constraint or index specified by
<parameter>conflict_target</parameter> is violated, the
alternative <parameter>conflict_action</parameter> is taken.
<literal>ON CONFLICT DO NOTHING</literal> simply avoids inserting
a row as its alternative action. <literal>ON CONFLICT DO
UPDATE</literal> updates the existing row that conflicts with the
row proposed for insertion as its alternative action.
</para>
<para>
<parameter>conflict_target</parameter> can perform
<emphasis>unique index inference</emphasis>. When performing
inference, it consists of one or more <replaceable
class="PARAMETER">column_name_index</replaceable> columns and/or
<replaceable class="PARAMETER">expression_index</replaceable>
expressions, and an optional <replaceable class="PARAMETER">
index_predicate</replaceable>. All <replaceable
class="PARAMETER">table_name</replaceable> unique indexes that,
without regard to order, contain exactly the
<parameter>conflict_target</parameter>-specified
columns/expressions are inferred (chosen) as arbiter indexes. If
an <replaceable class="PARAMETER">index_predicate</replaceable> is
specified, it must, as a further requirement for inference,
satisfy arbiter indexes. Note that this means a non-partial
unique index (a unique index without a predicate) will be inferred
(and thus used by <literal>ON CONFLICT</literal>) if such an index
satisfying every other criteria is available. If an attempt at
inference is unsuccessful, an error is raised.
</para>
<para>
<literal>ON CONFLICT DO UPDATE</literal> guarantees an atomic
<command>INSERT</command> or <command>UPDATE</command> outcome;
provided there is no independent error, one of those two outcomes
is guaranteed, even under high concurrency. This is also known as
<firstterm>UPSERT</firstterm> &mdash; <quote>UPDATE or
INSERT</quote>.
</para>
<variablelist>
<varlistentry>
<term><literal>conflict_target</literal></term>
<listitem>
<para>
Specifies which conflicts <literal>ON CONFLICT</literal> takes
the alternative action on by choosing <firstterm>arbiter
indexes</firstterm>. Either performs <emphasis>unique index
inference</emphasis>, or names a constraint explicitly. For
<literal>ON CONFLICT DO NOTHING</literal>, it is optional to
specify a <parameter>conflict_target</parameter>; when
omitted, conflicts with all usable constraints (and unique
indexes) are handled. For <literal>ON CONFLICT DO
UPDATE</literal>, a <parameter>conflict_target</parameter>
<emphasis>must</emphasis> be provided.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>conflict_action</literal></term>
<listitem>
<para>
<parameter>conflict_action</parameter> specifies an
alternative <literal>ON CONFLICT</literal> action. It can be
either <literal>DO NOTHING</literal>, or a <literal>DO
UPDATE</literal> clause specifying the exact details of the
<literal>UPDATE</literal> action to be performed in case of a
conflict. The <literal>SET</literal> and
<literal>WHERE</literal> clauses in <literal>ON CONFLICT DO
UPDATE</literal> have access to the existing row using the
table's name (or an alias), and to rows proposed for insertion
using the special <varname>excluded</varname> table.
<literal>SELECT</> privilege is required on any column in the
target table where corresponding <varname>excluded</varname>
columns are read.
</para>
<para>
Note that the effects of all per-row <literal>BEFORE
INSERT</literal> triggers are reflected in
<varname>excluded</varname> values, since those effects may
have contributed to the row being excluded from insertion.
</para>
</listitem>
</varlistentry>
<varlistentry> <varlistentry>
<term><replaceable class="PARAMETER">column_name_index</replaceable></term> <term><replaceable class="PARAMETER">column_name_index</replaceable></term>
<listitem> <listitem>
<para> <para>
The name of a <replaceable The name of a <replaceable
class="PARAMETER">table_name</replaceable> column. Part of a class="PARAMETER">table_name</replaceable> column. Used to
unique index inference clause. Follows <command>CREATE infer arbiter indexes. Follows <command>CREATE
INDEX</command> format. <literal>SELECT</> privilege on INDEX</command> format. <literal>SELECT</> privilege on
<replaceable class="PARAMETER">column_name_index</replaceable> <replaceable class="PARAMETER">column_name_index</replaceable>
is required. is required.
@ -291,10 +387,9 @@ INSERT INTO <replaceable class="PARAMETER">table_name</replaceable> [ AS <replac
class="PARAMETER">column_name_index</replaceable>, but used to class="PARAMETER">column_name_index</replaceable>, but used to
infer expressions on <replaceable infer expressions on <replaceable
class="PARAMETER">table_name</replaceable> columns appearing class="PARAMETER">table_name</replaceable> columns appearing
within index definitions (not simple columns). Part of unique within index definitions (not simple columns). Follows
index inference clause. Follows <command>CREATE INDEX</command> <command>CREATE INDEX</command> format. <literal>SELECT</>
format. <literal>SELECT</> privilege on any column appearing privilege on any column appearing within <replaceable
within <replaceable
class="PARAMETER">expression_index</replaceable> is required. class="PARAMETER">expression_index</replaceable> is required.
</para> </para>
</listitem> </listitem>
@ -306,11 +401,11 @@ INSERT INTO <replaceable class="PARAMETER">table_name</replaceable> [ AS <replac
<para> <para>
When specified, mandates that corresponding <replaceable When specified, mandates that corresponding <replaceable
class="PARAMETER">column_name_index</replaceable> or class="PARAMETER">column_name_index</replaceable> or
<replaceable class="PARAMETER">expression_index</replaceable> use a <replaceable class="PARAMETER">expression_index</replaceable>
particular collation in order to be matched in the inference clause. use a particular collation in order to be matched during
Typically this is omitted, as collations usually do not affect whether or inference. Typically this is omitted, as collations usually
not a constraint violation occurs. Follows <command>CREATE do not affect whether or not a constraint violation occurs.
INDEX</command> format. Follows <command>CREATE INDEX</command> format.
</para> </para>
</listitem> </listitem>
</varlistentry> </varlistentry>
@ -321,13 +416,14 @@ INSERT INTO <replaceable class="PARAMETER">table_name</replaceable> [ AS <replac
<para> <para>
When specified, mandates that corresponding <replaceable When specified, mandates that corresponding <replaceable
class="PARAMETER">column_name_index</replaceable> or class="PARAMETER">column_name_index</replaceable> or
<replaceable class="PARAMETER">expression_index</replaceable> use <replaceable class="PARAMETER">expression_index</replaceable>
particular operator class in order to be matched by the inference use particular operator class in order to be matched during
clause. Sometimes this is omitted because the inference. Typically this is omitted, as the
<emphasis>equality</emphasis> semantics are often equivalent across a <emphasis>equality</emphasis> semantics are often equivalent
type's operator classes anyway, or because it's sufficient to trust that across a type's operator classes anyway, or because it's
the defined unique indexes have the pertinent definition of equality. sufficient to trust that the defined unique indexes have the
Follows <command>CREATE INDEX</command> format. pertinent definition of equality. Follows <command>CREATE
INDEX</command> format.
</para> </para>
</listitem> </listitem>
</varlistentry> </varlistentry>
@ -336,13 +432,12 @@ INSERT INTO <replaceable class="PARAMETER">table_name</replaceable> [ AS <replac
<term><replaceable class="PARAMETER">index_predicate</replaceable></term> <term><replaceable class="PARAMETER">index_predicate</replaceable></term>
<listitem> <listitem>
<para> <para>
Used to allow inference of partial unique indexes. Any indexes Used to allow inference of partial unique indexes. Any
that satisfy the predicate (which need not actually be partial indexes that satisfy the predicate (which need not actually be
indexes) can be matched by the rest of the inference clause. partial indexes) can be inferred. Follows <command>CREATE
Follows <command>CREATE INDEX</command> format. INDEX</command> format. <literal>SELECT</> privilege on any
<literal>SELECT</> privilege on any column appearing within column appearing within <replaceable
<replaceable class="PARAMETER">index_predicate</replaceable> is class="PARAMETER">index_predicate</replaceable> is required.
required.
</para> </para>
</listitem> </listitem>
</varlistentry> </varlistentry>
@ -351,10 +446,9 @@ INSERT INTO <replaceable class="PARAMETER">table_name</replaceable> [ AS <replac
<term><replaceable class="PARAMETER">constraint_name</replaceable></term> <term><replaceable class="PARAMETER">constraint_name</replaceable></term>
<listitem> <listitem>
<para> <para>
Explicitly specifies an arbiter <emphasis>constraint</emphasis> Explicitly specifies an arbiter
by name, rather than inferring a constraint or index. This is <emphasis>constraint</emphasis> by name, rather than inferring
mostly useful for exclusion constraints, that cannot be chosen a constraint or index.
in the conventional way (with an inference clause).
</para> </para>
</listitem> </listitem>
</varlistentry> </varlistentry>
@ -363,118 +457,22 @@ INSERT INTO <replaceable class="PARAMETER">table_name</replaceable> [ AS <replac
<term><replaceable class="PARAMETER">condition</replaceable></term> <term><replaceable class="PARAMETER">condition</replaceable></term>
<listitem> <listitem>
<para> <para>
An expression that returns a value of type <type>boolean</type>. Only An expression that returns a value of type
rows for which this expression returns <literal>true</literal> will be <type>boolean</type>. Only rows for which this expression
updated, although all rows will be locked when the returns <literal>true</literal> will be updated, although all
<literal>ON CONFLICT DO UPDATE</> action is taken. rows will be locked when the <literal>ON CONFLICT DO UPDATE</>
action is taken. Note that
<replaceable>condition</replaceable> is evaluated last, after
a conflict has been identified as a candidate to update.
</para> </para>
</listitem> </listitem>
</varlistentry> </varlistentry>
</variablelist> </variablelist>
</refsect1>
<refsect1 id="sql-on-conflict">
<title id="sql-on-conflict-title"><literal>ON CONFLICT</literal> Clause</title>
<indexterm zone="SQL-INSERT">
<primary>UPSERT</primary>
</indexterm>
<indexterm zone="SQL-INSERT">
<primary>ON CONFLICT</primary>
</indexterm>
<para> <para>
The optional <literal>ON CONFLICT</literal> clause specifies an Note that exclusion constraints are not supported as arbiters with
alternative action to raising a unique violation or exclusion <literal>ON CONFLICT DO UPDATE</literal>. In all cases, only
constraint violation error. For each individual row proposed for <literal>NOT DEFERRABLE</literal> constraints and unique indexes
insertion, either the insertion proceeds, or, if a constraint are supported as arbiters.
specified by the <parameter>conflict_target</parameter> is
violated, the alternative <parameter>conflict_action</parameter> is
taken.
</para>
<para>
<parameter>conflict_target</parameter> describes which conflicts
are handled by the <literal>ON CONFLICT</literal> clause. Either a
<emphasis>unique index inference</emphasis> clause or an explicitly
named constraint can be used. For <literal>ON CONFLICT DO
NOTHING</literal>, it is optional to specify a
<parameter>conflict_target</parameter>; when omitted, conflicts
with all usable constraints (and unique indexes) are handled. For
<literal>ON CONFLICT DO UPDATE</literal>, a conflict target
<emphasis>must</emphasis> be specified.
Every time an insertion without <literal>ON CONFLICT</literal>
would ordinarily raise an error due to violating one of the
inferred (or explicitly named) constraints, a conflict (as in
<literal>ON CONFLICT</literal>) occurs, and the alternative action,
as specified by <parameter>conflict_action</parameter> is taken.
This happens on a row-by-row basis.
</para>
<para>
A <emphasis>unique index inference</emphasis> clause consists of
one or more <replaceable
class="PARAMETER">column_name_index</replaceable> columns and/or
<replaceable class="PARAMETER">expression_index</replaceable>
expressions, and an optional <replaceable class="PARAMETER">
index_predicate</replaceable>.
</para>
<para>
All the <replaceable class="PARAMETER">table_name</replaceable>
unique indexes that, without regard to order, contain exactly the
specified columns/expressions and, if specified, whose predicate
implies the <replaceable class="PARAMETER">
index_predicate</replaceable> are chosen as arbiter indexes. Note
that this means an index without a predicate will be used if a
non-partial index matching every other criteria happens to be
available.
</para>
<para>
If no index matches the inference clause (nor is there a constraint
explicitly named), an error is raised. Deferred constraints are
not supported as arbiters.
</para>
<para>
<parameter>conflict_action</parameter> defines the action to be
taken in case of conflict. <literal>ON CONFLICT DO
NOTHING</literal> simply avoids inserting a row as its alternative
action. <literal>ON CONFLICT DO UPDATE</literal> updates the
existing row that conflicts with the row proposed for insertion as
its alternative action.
<literal>ON CONFLICT DO UPDATE</literal> guarantees an atomic
<command>INSERT</command> or <command>UPDATE</command> outcome - provided
there is no independent error, one of those two outcomes is guaranteed,
even under high concurrency. This feature is also known as
<firstterm>UPSERT</firstterm>.
Note that exclusion constraints are not supported with
<literal>ON CONFLICT DO UPDATE</literal>.
</para>
<para>
<literal>ON CONFLICT DO UPDATE</literal> optionally accepts
a <literal>WHERE</literal> clause <replaceable>condition</replaceable>.
When provided, the statement only proceeds with updating if
the <replaceable>condition</replaceable> is satisfied. Otherwise, unlike a
conventional <command>UPDATE</command>, the row is still locked for update.
Note that the <replaceable>condition</replaceable> is evaluated last, after
a conflict has been identified as a candidate to update.
</para>
<para>
The <literal>SET</literal> and <literal>WHERE</literal> clauses in
<literal>ON CONFLICT UPDATE</literal> have access to the existing
row, using the table's name, and to the row
proposed for insertion, using the <varname>excluded</varname>
alias. The <varname>excluded</varname> alias requires
<literal>SELECT</> privilege on any column whose values are read.
Note that the effects of all per-row <literal>BEFORE INSERT</literal>
triggers are reflected in <varname>excluded</varname> values, since those
effects may have contributed to the row being excluded from insertion.
</para> </para>
<para> <para>
@ -482,10 +480,25 @@ INSERT INTO <replaceable class="PARAMETER">table_name</replaceable> [ AS <replac
clause is a <quote>deterministic</quote> statement. This means clause is a <quote>deterministic</quote> statement. This means
that the command will not be allowed to affect any single existing that the command will not be allowed to affect any single existing
row more than once; a cardinality violation error will be raised row more than once; a cardinality violation error will be raised
when this situation arises. Rows proposed for insertion should not when this situation arises. Rows proposed for insertion should
duplicate each other in terms of attributes constrained by the not duplicate each other in terms of attributes constrained by an
conflict-arbitrating unique index. arbiter index or constraint. Note that exclusion constraints are
not supported with <literal>ON CONFLICT DO UPDATE</literal>.
</para> </para>
<tip>
<para>
It is often preferable to use unique index inference rather than
naming a constraint directly using <literal>ON CONFLICT ON
CONSTRAINT</literal> <replaceable class="PARAMETER">
constraint_name</replaceable>. Inference will continue to work
correctly when the underlying index is replaced by another more
or less equivalent index in an overlapping way, for example when
using <literal>CREATE UNIQUE INDEX ... CONCURRENTLY</literal>
before dropping the index being replaced.
</para>
</tip>
</refsect2>
</refsect1> </refsect1>
<refsect1> <refsect1>
@ -617,12 +630,12 @@ INSERT INTO employees_log SELECT *, current_timestamp FROM upd;
<para> <para>
Insert or update new distributors as appropriate. Assumes a unique Insert or update new distributors as appropriate. Assumes a unique
index has been defined that constrains values appearing in the index has been defined that constrains values appearing in the
<literal>did</literal> column. Note that an <varname>EXCLUDED</> <literal>did</literal> column. Note that the special
expression is used to reference values originally proposed for <varname>excluded</> table is used to reference values originally
insertion: proposed for insertion:
<programlisting> <programlisting>
INSERT INTO distributors (did, dname) INSERT INTO distributors (did, dname)
VALUES (5, 'Gizmo transglobal'), (6, 'Associated Computing, inc') VALUES (5, 'Gizmo Transglobal'), (6, 'Associated Computing, Inc')
ON CONFLICT (did) DO UPDATE SET dname = EXCLUDED.dname; ON CONFLICT (did) DO UPDATE SET dname = EXCLUDED.dname;
</programlisting> </programlisting>
</para> </para>