Skip to content

Commit

Permalink
Add support for INSERT ... ON CONFLICT DO NOTHING/UPDATE.
Browse files Browse the repository at this point in the history
The newly added ON CONFLICT clause allows to specify an alternative to
raising a unique or exclusion constraint violation error when inserting.
ON CONFLICT refers to constraints that can either be specified using a
inference clause (by specifying the columns of a unique constraint) or
by naming a unique or exclusion constraint.  DO NOTHING avoids the
constraint violation, without touching the pre-existing row.  DO UPDATE
SET ... [WHERE ...] updates the pre-existing tuple, and has access to
both the tuple proposed for insertion and the existing tuple; the
optional WHERE clause can be used to prevent an update from being
executed.  The UPDATE SET and WHERE clauses have access to the tuple
proposed for insertion using the "magic" EXCLUDED alias, and to the
pre-existing tuple using the table name or its alias.

This feature is often referred to as upsert.

This is implemented using a new infrastructure called "speculative
insertion". It is an optimistic variant of regular insertion that first
does a pre-check for existing tuples and then attempts an insert.  If a
violating tuple was inserted concurrently, the speculatively inserted
tuple is deleted and a new attempt is made.  If the pre-check finds a
matching tuple the alternative DO NOTHING or DO UPDATE action is taken.
If the insertion succeeds without detecting a conflict, the tuple is
deemed inserted.

To handle the possible ambiguity between the excluded alias and a table
named excluded, and for convenience with long relation names, INSERT
INTO now can alias its target table.

Bumps catversion as stored rules change.

Author: Peter Geoghegan, with significant contributions from Heikki
    Linnakangas and Andres Freund. Testing infrastructure by Jeff Janes.
Reviewed-By: Heikki Linnakangas, Andres Freund, Robert Haas, Simon Riggs,
    Dean Rasheed, Stephen Frost and many others.
  • Loading branch information
anarazel committed May 8, 2015
1 parent 2c8f483 commit 168d580
Show file tree
Hide file tree
Showing 122 changed files with 6,106 additions and 435 deletions.
25 changes: 25 additions & 0 deletions contrib/pg_stat_statements/pg_stat_statements.c
Original file line number Diff line number Diff line change
Expand Up @@ -2264,6 +2264,7 @@ JumbleQuery(pgssJumbleState *jstate, Query *query)
JumbleRangeTable(jstate, query->rtable);
JumbleExpr(jstate, (Node *) query->jointree);
JumbleExpr(jstate, (Node *) query->targetList);
JumbleExpr(jstate, (Node *) query->onConflict);
JumbleExpr(jstate, (Node *) query->returningList);
JumbleExpr(jstate, (Node *) query->groupClause);
JumbleExpr(jstate, query->havingQual);
Expand Down Expand Up @@ -2631,6 +2632,16 @@ JumbleExpr(pgssJumbleState *jstate, Node *node)
APP_JUMB(ce->cursor_param);
}
break;
case T_InferenceElem:
{
InferenceElem *ie = (InferenceElem *) node;

APP_JUMB(ie->infercollid);
APP_JUMB(ie->inferopfamily);
APP_JUMB(ie->inferopcinputtype);
JumbleExpr(jstate, ie->expr);
}
break;
case T_TargetEntry:
{
TargetEntry *tle = (TargetEntry *) node;
Expand Down Expand Up @@ -2667,6 +2678,20 @@ JumbleExpr(pgssJumbleState *jstate, Node *node)
JumbleExpr(jstate, from->quals);
}
break;
case T_OnConflictExpr:
{
OnConflictExpr *conf = (OnConflictExpr *) node;

APP_JUMB(conf->action);
JumbleExpr(jstate, (Node *) conf->arbiterElems);
JumbleExpr(jstate, conf->arbiterWhere);
JumbleExpr(jstate, (Node *) conf->onConflictSet);
JumbleExpr(jstate, conf->onConflictWhere);
APP_JUMB(conf->constraint);
APP_JUMB(conf->exclRelIndex);
JumbleExpr(jstate, (Node *) conf->exclRelTlist);
}
break;
case T_List:
foreach(temp, (List *) node)
{
Expand Down
7 changes: 5 additions & 2 deletions contrib/postgres_fdw/deparse.c
Original file line number Diff line number Diff line change
Expand Up @@ -847,8 +847,8 @@ appendWhereClause(StringInfo buf,
void
deparseInsertSql(StringInfo buf, PlannerInfo *root,
Index rtindex, Relation rel,
List *targetAttrs, List *returningList,
List **retrieved_attrs)
List *targetAttrs, bool doNothing,
List *returningList, List **retrieved_attrs)
{
AttrNumber pindex;
bool first;
Expand Down Expand Up @@ -892,6 +892,9 @@ deparseInsertSql(StringInfo buf, PlannerInfo *root,
else
appendStringInfoString(buf, " DEFAULT VALUES");

if (doNothing)
appendStringInfoString(buf, " ON CONFLICT DO NOTHING");

deparseReturningList(buf, root, rtindex, rel,
rel->trigdesc && rel->trigdesc->trig_insert_after_row,
returningList, retrieved_attrs);
Expand Down
5 changes: 5 additions & 0 deletions contrib/postgres_fdw/expected/postgres_fdw.out
Original file line number Diff line number Diff line change
Expand Up @@ -2327,6 +2327,11 @@ INSERT INTO ft1(c1, c2) VALUES(11, 12); -- duplicate key
ERROR: duplicate key value violates unique constraint "t1_pkey"
DETAIL: Key ("C 1")=(11) already exists.
CONTEXT: Remote SQL command: INSERT INTO "S 1"."T 1"("C 1", c2, c3, c4, c5, c6, c7, c8) VALUES ($1, $2, $3, $4, $5, $6, $7, $8)
INSERT INTO ft1(c1, c2) VALUES(11, 12) ON CONFLICT DO NOTHING; -- works
INSERT INTO ft1(c1, c2) VALUES(11, 12) ON CONFLICT (c1, c2) DO NOTHING; -- unsupported
ERROR: there is no unique or exclusion constraint matching the ON CONFLICT specification
INSERT INTO ft1(c1, c2) VALUES(11, 12) ON CONFLICT (c1, c2) DO UPDATE SET c3 = 'ffg'; -- unsupported
ERROR: there is no unique or exclusion constraint matching the ON CONFLICT specification
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).
Expand Down
15 changes: 14 additions & 1 deletion contrib/postgres_fdw/postgres_fdw.c
Original file line number Diff line number Diff line change
Expand Up @@ -1171,6 +1171,7 @@ postgresPlanForeignModify(PlannerInfo *root,
List *targetAttrs = NIL;
List *returningList = NIL;
List *retrieved_attrs = NIL;
bool doNothing = false;

initStringInfo(&sql);

Expand Down Expand Up @@ -1222,14 +1223,26 @@ postgresPlanForeignModify(PlannerInfo *root,
if (plan->returningLists)
returningList = (List *) list_nth(plan->returningLists, subplan_index);

/*
* ON CONFLICT DO UPDATE and DO NOTHING case with inference specification
* should have already been rejected in the optimizer, as presently there
* is no way to recognize an arbiter index on a foreign table. Only DO
* NOTHING is supported without an inference specification.
*/
if (plan->onConflictAction == ONCONFLICT_NOTHING)
doNothing = true;
else if (plan->onConflictAction != ONCONFLICT_NONE)
elog(ERROR, "unexpected ON CONFLICT specification: %d",
(int) plan->onConflictAction);

/*
* Construct the SQL command string.
*/
switch (operation)
{
case CMD_INSERT:
deparseInsertSql(&sql, root, resultRelation, rel,
targetAttrs, returningList,
targetAttrs, doNothing, returningList,
&retrieved_attrs);
break;
case CMD_UPDATE:
Expand Down
2 changes: 1 addition & 1 deletion contrib/postgres_fdw/postgres_fdw.h
Original file line number Diff line number Diff line change
Expand Up @@ -60,7 +60,7 @@ extern void appendWhereClause(StringInfo buf,
List **params);
extern void deparseInsertSql(StringInfo buf, PlannerInfo *root,
Index rtindex, Relation rel,
List *targetAttrs, List *returningList,
List *targetAttrs, bool doNothing, List *returningList,
List **retrieved_attrs);
extern void deparseUpdateSql(StringInfo buf, PlannerInfo *root,
Index rtindex, Relation rel,
Expand Down
3 changes: 3 additions & 0 deletions contrib/postgres_fdw/sql/postgres_fdw.sql
Original file line number Diff line number Diff line change
Expand Up @@ -372,6 +372,9 @@ UPDATE ft2 SET c2 = c2 + 600 WHERE c1 % 10 = 8 AND c1 < 1200 RETURNING *;
ALTER TABLE "S 1"."T 1" ADD CONSTRAINT c2positive CHECK (c2 >= 0);

INSERT INTO ft1(c1, c2) VALUES(11, 12); -- duplicate key
INSERT INTO ft1(c1, c2) VALUES(11, 12) ON CONFLICT DO NOTHING; -- works
INSERT INTO ft1(c1, c2) VALUES(11, 12) ON CONFLICT (c1, c2) DO NOTHING; -- unsupported
INSERT INTO ft1(c1, c2) VALUES(11, 12) ON CONFLICT (c1, c2) DO UPDATE SET c3 = 'ffg'; -- unsupported
INSERT INTO ft1(c1, c2) VALUES(1111, -2); -- c2positive
UPDATE ft1 SET c2 = -c2 WHERE c1 = 1; -- c2positive

Expand Down
34 changes: 34 additions & 0 deletions contrib/test_decoding/expected/ddl.out
Original file line number Diff line number Diff line change
Expand Up @@ -148,6 +148,24 @@ SELECT data FROM pg_logical_slot_get_changes('regression_slot', NULL, NULL, 'inc
COMMIT
(9 rows)

-- ON CONFLICT DO UPDATE support
BEGIN;
INSERT INTO replication_example(id, somedata, somenum) SELECT i, i, i FROM generate_series(-15, 15) i
ON CONFLICT (id) DO 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);
Expand Down Expand Up @@ -196,6 +214,22 @@ ORDER BY 1,2;
20467 | table public.tr_etoomuch: DELETE: id[integer]:1 | table public.tr_etoomuch: UPDATE: id[integer]:9999 data[integer]:-9999
(3 rows)

-- check that a large, spooled, upsert works
INSERT INTO tr_etoomuch (id, data)
SELECT g.i, -g.i FROM generate_series(8000, 12000) g(i)
ON CONFLICT(id) DO UPDATE SET data = EXCLUDED.data;
SELECT substring(data, 1, 29), count(*)
FROM pg_logical_slot_get_changes('regression_slot', NULL, NULL, 'include-xids', '0', 'skip-empty-xacts', '1')
GROUP BY 1
ORDER BY min(location - '0/0');
substring | count
-------------------------------+-------
BEGIN | 1
table public.tr_etoomuch: UPD | 2235
table public.tr_etoomuch: INS | 1766
COMMIT | 1
(4 rows)

/*
* check whether we decode subtransactions correctly in relation with each
* other
Expand Down
9 changes: 8 additions & 1 deletion contrib/test_decoding/expected/toast.out
Original file line number Diff line number Diff line change
Expand Up @@ -23,6 +23,10 @@ INSERT INTO xpto (toasted_col2) SELECT repeat(string_agg(to_char(g.i, 'FM0000'),
-- update of existing column
UPDATE xpto SET toasted_col1 = (SELECT string_agg(g.i::text, '') FROM generate_series(1, 2000) g(i)) WHERE id = 1;
UPDATE xpto SET rand1 = 123.456 WHERE id = 1;
-- updating external via INSERT ... ON CONFLICT DO UPDATE
INSERT INTO xpto(id, toasted_col2) VALUES (2, 'toasted2-upsert')
ON CONFLICT (id)
DO UPDATE SET toasted_col2 = EXCLUDED.toasted_col2 || xpto.toasted_col2;
DELETE FROM xpto WHERE id = 1;
DROP TABLE IF EXISTS toasted_key;
NOTICE: table "toasted_key" does not exist, skipping
Expand Down Expand Up @@ -64,6 +68,9 @@ SELECT substr(data, 1, 200) FROM pg_logical_slot_get_changes('regression_slot',
table public.xpto: UPDATE: id[integer]:1 toasted_col1[text]:unchanged-toast-datum rand1[double precision]:123.456 toasted_col2[text]:unchanged-toast-datum rand2[double precision]:1578
COMMIT
BEGIN
table public.xpto: UPDATE: id[integer]:2 toasted_col1[text]:null rand1[double precision]:3077 toasted_col2[text]:'toasted2-upsert00010002000300040005000600070008000900100011001200130014001500160017001
COMMIT
BEGIN
table public.xpto: DELETE: id[integer]:1
COMMIT
BEGIN
Expand Down Expand Up @@ -283,7 +290,7 @@ SELECT substr(data, 1, 200) FROM pg_logical_slot_get_changes('regression_slot',
table public.toasted_copy: INSERT: id[integer]:202 data[text]:'untoasted199'
table public.toasted_copy: INSERT: id[integer]:203 data[text]:'untoasted200'
COMMIT
(232 rows)
(235 rows)

SELECT pg_drop_replication_slot('regression_slot');
pg_drop_replication_slot
Expand Down
22 changes: 22 additions & 0 deletions contrib/test_decoding/sql/ddl.sql
Original file line number Diff line number Diff line change
Expand Up @@ -84,6 +84,18 @@ COMMIT;
-- show changes
SELECT data FROM pg_logical_slot_get_changes('regression_slot', NULL, NULL, 'include-xids', '0', 'skip-empty-xacts', '1');

-- ON CONFLICT DO UPDATE support
BEGIN;
INSERT INTO replication_example(id, somedata, somenum) SELECT i, i, i FROM generate_series(-15, 15) i
ON CONFLICT (id) DO 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);
Expand Down Expand Up @@ -114,6 +126,16 @@ FROM pg_logical_slot_get_changes('regression_slot', NULL, NULL, 'include-xids',
GROUP BY substring(data, 1, 24)
ORDER BY 1,2;

-- check that a large, spooled, upsert works
INSERT INTO tr_etoomuch (id, data)
SELECT g.i, -g.i FROM generate_series(8000, 12000) g(i)
ON CONFLICT(id) DO UPDATE SET data = EXCLUDED.data;

SELECT substring(data, 1, 29), count(*)
FROM pg_logical_slot_get_changes('regression_slot', NULL, NULL, 'include-xids', '0', 'skip-empty-xacts', '1')
GROUP BY 1
ORDER BY min(location - '0/0');

/*
* check whether we decode subtransactions correctly in relation with each
* other
Expand Down
5 changes: 5 additions & 0 deletions contrib/test_decoding/sql/toast.sql
Original file line number Diff line number Diff line change
Expand Up @@ -25,6 +25,11 @@ UPDATE xpto SET toasted_col1 = (SELECT string_agg(g.i::text, '') FROM generate_s

UPDATE xpto SET rand1 = 123.456 WHERE id = 1;

-- updating external via INSERT ... ON CONFLICT DO UPDATE
INSERT INTO xpto(id, toasted_col2) VALUES (2, 'toasted2-upsert')
ON CONFLICT (id)
DO UPDATE SET toasted_col2 = EXCLUDED.toasted_col2 || xpto.toasted_col2;

DELETE FROM xpto WHERE id = 1;

DROP TABLE IF EXISTS toasted_key;
Expand Down
7 changes: 7 additions & 0 deletions doc/src/sgml/fdwhandler.sgml
Original file line number Diff line number Diff line change
Expand Up @@ -1050,6 +1050,13 @@ GetForeignServerByName(const char *name, bool missing_ok);
source provides.
</para>

<para>
<command>INSERT</> with an <literal>ON CONFLICT</> clause does not
support specifying the conflict target, as remote constraints are not
locally known. This in turn implies that <literal>ON CONFLICT DO
UPDATE</> is not supported, since the specification is mandatory there.
</para>

</sect1>

</chapter>
7 changes: 7 additions & 0 deletions doc/src/sgml/keywords.sgml
Original file line number Diff line number Diff line change
Expand Up @@ -853,6 +853,13 @@
<entry></entry>
<entry></entry>
</row>
<row>
<entry><token>CONFLICT</token></entry>
<entry>non-reserved</entry>
<entry></entry>
<entry></entry>
<entry></entry>
</row>
<row>
<entry><token>CONNECT</token></entry>
<entry></entry>
Expand Down
23 changes: 21 additions & 2 deletions doc/src/sgml/mvcc.sgml
Original file line number Diff line number Diff line change
Expand Up @@ -326,8 +326,27 @@
</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
<command>INSERT</command> with an <literal>ON CONFLICT DO UPDATE</> clause
behaves similarly. In Read Committed mode, each row proposed for insertion
will either insert or update. Unless there are unrelated errors, one of
those two outcomes is guaranteed. If a conflict originates in another
transaction whose effects are not yet visible to the <command>INSERT
</command>, the <command>UPDATE</command> clause will affect that row,
even though possibly <emphasis>no</> version of that row is
conventionally visible to the command.
</para>

<para>
<command>INSERT</command> with an <literal>ON CONFLICT DO
NOTHING</> 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 rules, it is possible for an updating command to see
an inconsistent snapshot: it can see the effects of concurrent updating
commands on the same rows it is trying to update, but it
does not see effects of those commands on other rows in the database.
This behavior makes Read Committed mode unsuitable for commands that
Expand Down
14 changes: 10 additions & 4 deletions doc/src/sgml/plpgsql.sgml
Original file line number Diff line number Diff line change
Expand Up @@ -2623,7 +2623,11 @@ END;
<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 DO UPDATE</> rather than actually using
this pattern. This example serves primarily to illustrate use of
<application>PL/pgSQL</application> control flow structures:

<programlisting>
CREATE TABLE db (a INT PRIMARY KEY, b TEXT);
Expand Down Expand Up @@ -3852,9 +3856,11 @@ ASSERT <replaceable class="parameter">condition</replaceable> <optional> , <repl
<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 DO
UPDATE</> clause). For <command>DELETE</> operations, the return
value should be <varname>OLD</>.
</para>

<para>
Expand Down
8 changes: 8 additions & 0 deletions doc/src/sgml/postgres-fdw.sgml
Original file line number Diff line number Diff line change
Expand Up @@ -68,6 +68,14 @@
in your user mapping must have privileges to do these things.)
</para>

<para>
Note that <filename>postgres_fdw</> currently lacks support for
<command>INSERT</command> statements with an <literal>ON CONFLICT DO
UPDATE</> clause. However, the <literal>ON CONFLICT DO NOTHING</>
clause is supported, provided a unique index inference specification
is omitted.
</para>

<para>
It is generally recommended that the columns of a foreign table be declared
with exactly the same data types, and collations if applicable, as the
Expand Down
13 changes: 10 additions & 3 deletions doc/src/sgml/protocol.sgml
Original file line number Diff line number Diff line change
Expand Up @@ -2998,9 +2998,16 @@ CommandComplete (B)
<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>

Expand Down
Loading

4 comments on commit 168d580

@billschaller
Copy link

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

YES

@applegao
Copy link

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

how can I get the patch??? I want to get this patch,please help me !

@kotsachin
Copy link

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

@Tiggs
Copy link

@Tiggs Tiggs commented on 168d580 Apr 23, 2016 via email

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Please sign in to comment.