[PATCH] Make ON CONFLICT DO NOTHING and ON CONFLICT DO UPDATE consistent
Hi hackers,
Currently we allow self-conflicting inserts for ON CONFLICT DO NOTHING:
```
CREATE TABLE t (a INT UNIQUE, b INT);
INSERT INTO t VALUES (1,1), (1,2) ON CONFLICT DO NOTHING;
-- succeeds, inserting the first row and ignoring the second
```
... but not for ON CONFLICT .. DO UPDATE:
```
INSERT INTO t VALUES (1,1), (1,2) ON CONFLICT (a) DO UPDATE SET b = 0;
ERROR: ON CONFLICT DO UPDATE command cannot affect row a second time
HINT: Ensure that no rows proposed for insertion within the same
command have duplicate constrained values.
```
Tom pointed out in 2016 that this is actually a bug [1]/messages/by-id/22438.1477265185@sss.pgh.pa.us and I agree.
The proposed patch fixes this.
[1]: /messages/by-id/22438.1477265185@sss.pgh.pa.us
--
Best regards,
Aleksander Alekseev
Attachments:
v1-0001-Make-ON-CONFLICT-DO-NOTHING-and-ON-CONFLICT-DO-UP.patchapplication/octet-stream; name=v1-0001-Make-ON-CONFLICT-DO-NOTHING-and-ON-CONFLICT-DO-UP.patchDownload
From 97cec6232bdf8ccaf298d894f71a7f2760e2edd5 Mon Sep 17 00:00:00 2001
From: Aleksander Alekseev <aleksander@timescale.com>
Date: Wed, 25 Jan 2023 15:59:35 +0300
Subject: [PATCH v1] Make ON CONFLICT DO NOTHING and ON CONFLICT DO UPDATE
consistent
Prior to this commit we allowed self-conflicting inserts for DO NOTHING:
CREATE TABLE t (a INT UNIQUE, b INT);
INSERT INTO t VALUES (1,1), (1,2) ON CONFLICT DO NOTHING;
-- succeeds, inserting the first row and ignoring the second
... but not for DO UPDATE:
INSERT INTO t VALUES (1,1), (1,2) ON CONFLICT (a) DO UPDATE SET b = 0;
ERROR: ON CONFLICT DO UPDATE command cannot affect row a second time
Now DO UPDATE is handled similarly to DO NOTHING.
Author: Aleksander Alekseev
Reviewed-by: TODO FIXME
Discussion: TODO FIXME
---
doc/src/sgml/ref/insert.sgml | 4 +-
src/backend/access/heap/heapam.c | 20 ++++++++-
src/backend/access/heap/heapam_handler.c | 4 +-
src/backend/access/table/tableam.c | 3 +-
src/backend/executor/nodeModifyTable.c | 43 ++++++++-----------
src/include/access/heapam.h | 3 +-
src/include/access/tableam.h | 7 +--
src/test/regress/expected/constraints.out | 28 ++++++------
src/test/regress/expected/insert_conflict.out | 17 +++-----
src/test/regress/sql/constraints.sql | 4 +-
src/test/regress/sql/insert_conflict.sql | 6 +--
11 files changed, 74 insertions(+), 65 deletions(-)
diff --git a/doc/src/sgml/ref/insert.sgml b/doc/src/sgml/ref/insert.sgml
index 7cea70329e..368e6f5bd6 100644
--- a/doc/src/sgml/ref/insert.sgml
+++ b/doc/src/sgml/ref/insert.sgml
@@ -531,9 +531,7 @@ INSERT INTO <replaceable class="parameter">table_name</replaceable> [ AS <replac
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 an
- arbiter index or constraint.
+ when this situation arises.
</para>
<para>
diff --git a/src/backend/access/heap/heapam.c b/src/backend/access/heap/heapam.c
index e6024a980b..37a3be7f09 100644
--- a/src/backend/access/heap/heapam.c
+++ b/src/backend/access/heap/heapam.c
@@ -3129,7 +3129,7 @@ simple_heap_delete(Relation relation, ItemPointer tid)
TM_Result
heap_update(Relation relation, ItemPointer otid, HeapTuple newtup,
CommandId cid, Snapshot crosscheck, bool wait,
- TM_FailureData *tmfd, LockTupleMode *lockmode)
+ TM_FailureData *tmfd, LockTupleMode *lockmode, bool force_visibility)
{
TM_Result result;
TransactionId xid = GetCurrentTransactionId();
@@ -3299,6 +3299,21 @@ l2:
locker_remains = false;
result = HeapTupleSatisfiesUpdate(&oldtup, cid, buffer);
+ if (force_visibility && (result == TM_Invisible))
+ {
+ /*
+ * Special case of ON CONFLICT .. DO UPDATE with conflicting tuples
+ * created within the same command. Normally a command doesn't see the
+ * tuples created by this command e.g. to avoid Halloween problem.
+ * However in this particular case we want to treat the tuples as if
+ * they were inserted by the previosly executed command.
+ *
+ * This is done in order to make the behavior consistent with ON
+ * CONFLICT .. DO NOTHING.
+ */
+ result = TM_Ok;
+ }
+
/* see below about the "no wait" case */
Assert(result != TM_BeingModified || wait);
@@ -3457,6 +3472,7 @@ l2:
LockBuffer(buffer, BUFFER_LOCK_UNLOCK);
heap_acquire_tuplock(relation, &(oldtup.t_self), *lockmode,
LockWaitBlock, &have_tuple_lock);
+
XactLockTableWait(xwait, relation, &oldtup.t_self,
XLTW_Update);
checked_lockers = true;
@@ -4174,7 +4190,7 @@ simple_heap_update(Relation relation, ItemPointer otid, HeapTuple tup)
result = heap_update(relation, otid, tup,
GetCurrentCommandId(true), InvalidSnapshot,
true /* wait for commit */ ,
- &tmfd, &lockmode);
+ &tmfd, &lockmode, false);
switch (result)
{
case TM_SelfModified:
diff --git a/src/backend/access/heap/heapam_handler.c b/src/backend/access/heap/heapam_handler.c
index c4b1916d36..001addd780 100644
--- a/src/backend/access/heap/heapam_handler.c
+++ b/src/backend/access/heap/heapam_handler.c
@@ -314,7 +314,7 @@ static TM_Result
heapam_tuple_update(Relation relation, ItemPointer otid, TupleTableSlot *slot,
CommandId cid, Snapshot snapshot, Snapshot crosscheck,
bool wait, TM_FailureData *tmfd,
- LockTupleMode *lockmode, bool *update_indexes)
+ LockTupleMode *lockmode, bool *update_indexes, bool force_visibility)
{
bool shouldFree = true;
HeapTuple tuple = ExecFetchSlotHeapTuple(slot, true, &shouldFree);
@@ -325,7 +325,7 @@ heapam_tuple_update(Relation relation, ItemPointer otid, TupleTableSlot *slot,
tuple->t_tableOid = slot->tts_tableOid;
result = heap_update(relation, otid, tuple, cid, crosscheck, wait,
- tmfd, lockmode);
+ tmfd, lockmode, force_visibility);
ItemPointerCopy(&tuple->t_self, &slot->tts_tid);
/*
diff --git a/src/backend/access/table/tableam.c b/src/backend/access/table/tableam.c
index ef0d34fcee..065c8e9e74 100644
--- a/src/backend/access/table/tableam.c
+++ b/src/backend/access/table/tableam.c
@@ -355,7 +355,8 @@ simple_table_tuple_update(Relation rel, ItemPointer otid,
GetCurrentCommandId(true),
snapshot, InvalidSnapshot,
true /* wait for commit */ ,
- &tmfd, &lockmode, update_indexes);
+ &tmfd, &lockmode, update_indexes,
+ false /* don't force visibility */ );
switch (result)
{
diff --git a/src/backend/executor/nodeModifyTable.c b/src/backend/executor/nodeModifyTable.c
index f419c47065..2baf1ea7f5 100644
--- a/src/backend/executor/nodeModifyTable.c
+++ b/src/backend/executor/nodeModifyTable.c
@@ -1955,7 +1955,7 @@ ExecUpdatePrepareSlot(ResultRelInfo *resultRelInfo,
static TM_Result
ExecUpdateAct(ModifyTableContext *context, ResultRelInfo *resultRelInfo,
ItemPointer tupleid, HeapTuple oldtuple, TupleTableSlot *slot,
- bool canSetTag, UpdateContext *updateCxt)
+ bool canSetTag, UpdateContext *updateCxt, bool force_visibility)
{
EState *estate = context->estate;
Relation resultRelationDesc = resultRelInfo->ri_RelationDesc;
@@ -2089,7 +2089,7 @@ lreplace:
estate->es_crosscheck_snapshot,
true /* wait for commit */ ,
&context->tmfd, &updateCxt->lockmode,
- &updateCxt->updateIndexes);
+ &updateCxt->updateIndexes, force_visibility);
if (result == TM_Ok)
updateCxt->updated = true;
@@ -2240,7 +2240,7 @@ ExecCrossPartitionUpdateForeignKey(ModifyTableContext *context,
static TupleTableSlot *
ExecUpdate(ModifyTableContext *context, ResultRelInfo *resultRelInfo,
ItemPointer tupleid, HeapTuple oldtuple, TupleTableSlot *slot,
- bool canSetTag)
+ bool canSetTag, bool force_visibility)
{
EState *estate = context->estate;
Relation resultRelationDesc = resultRelInfo->ri_RelationDesc;
@@ -2298,7 +2298,7 @@ ExecUpdate(ModifyTableContext *context, ResultRelInfo *resultRelInfo,
redo_act:
result = ExecUpdateAct(context, resultRelInfo, tupleid, oldtuple, slot,
- canSetTag, &updateCxt);
+ canSetTag, &updateCxt, force_visibility);
/*
* If ExecUpdateAct reports that a cross-partition update was done,
@@ -2496,6 +2496,9 @@ ExecOnConflictUpdate(ModifyTableContext *context,
TransactionId xmin;
bool isnull;
+ /* Is this a case of conflicting tuples created within the same command? */
+ bool conflict_within_command = false;
+
/* Determine lock mode to use */
lockmode = ExecUpdateLockMode(context->estate, resultRelInfo);
@@ -2522,17 +2525,6 @@ ExecOnConflictUpdate(ModifyTableContext *context,
* This can occur when a just inserted tuple is updated again in
* the same command. E.g. because multiple rows with the same
* conflicting key values are inserted.
- *
- * This is somewhat similar to the ExecUpdate() TM_SelfModified
- * case. We do not want to proceed because it would lead to the
- * same row being updated a second time in some unspecified order,
- * and in contrast to plain UPDATEs there's no historical behavior
- * to break.
- *
- * It is the user's responsibility to prevent this situation from
- * occurring. These problems are why the SQL standard similarly
- * specifies that for SQL MERGE, an exception must be raised in
- * the event of an attempt to update the same row twice.
*/
xminDatum = slot_getsysattr(existing,
MinTransactionIdAttributeNumber,
@@ -2541,12 +2533,14 @@ ExecOnConflictUpdate(ModifyTableContext *context,
xmin = DatumGetTransactionId(xminDatum);
if (TransactionIdIsCurrentTransactionId(xmin))
- ereport(ERROR,
- (errcode(ERRCODE_CARDINALITY_VIOLATION),
- /* translator: %s is a SQL command name */
- errmsg("%s command cannot affect row a second time",
- "ON CONFLICT DO UPDATE"),
- errhint("Ensure that no rows proposed for insertion within the same command have duplicate constrained values.")));
+ {
+ /*
+ * Detect the case of ON CONFLICT .. DO UPDATE .. with
+ * conflicting tuples created within the same command.
+ */
+ conflict_within_command = true;
+ break;
+ }
/* This shouldn't happen */
elog(ERROR, "attempted to lock invisible tuple");
@@ -2674,7 +2668,7 @@ ExecOnConflictUpdate(ModifyTableContext *context,
*returning = ExecUpdate(context, resultRelInfo,
conflictTid, NULL,
resultRelInfo->ri_onConflict->oc_ProjSlot,
- canSetTag);
+ canSetTag, conflict_within_command);
/*
* Clear out existing tuple, as there might not be another conflict among
@@ -2881,7 +2875,8 @@ lmerge_matched:
}
ExecUpdatePrepareSlot(resultRelInfo, newslot, context->estate);
result = ExecUpdateAct(context, resultRelInfo, tupleid, NULL,
- newslot, mtstate->canSetTag, &updateCxt);
+ newslot, mtstate->canSetTag, &updateCxt,
+ false);
if (result == TM_Ok && updateCxt.updated)
{
ExecUpdateEpilogue(context, &updateCxt, resultRelInfo,
@@ -3847,7 +3842,7 @@ ExecModifyTable(PlanState *pstate)
/* Now apply the update. */
slot = ExecUpdate(&context, resultRelInfo, tupleid, oldtuple,
- slot, node->canSetTag);
+ slot, node->canSetTag, false);
break;
case CMD_DELETE:
diff --git a/src/include/access/heapam.h b/src/include/access/heapam.h
index 417108f1e0..023aeff1a6 100644
--- a/src/include/access/heapam.h
+++ b/src/include/access/heapam.h
@@ -249,7 +249,8 @@ extern void heap_abort_speculative(Relation relation, ItemPointer tid);
extern TM_Result heap_update(Relation relation, ItemPointer otid,
HeapTuple newtup,
CommandId cid, Snapshot crosscheck, bool wait,
- struct TM_FailureData *tmfd, LockTupleMode *lockmode);
+ struct TM_FailureData *tmfd, LockTupleMode *lockmode,
+ bool force_visibility);
extern TM_Result heap_lock_tuple(Relation relation, HeapTuple tuple,
CommandId cid, LockTupleMode mode, LockWaitPolicy wait_policy,
bool follow_updates,
diff --git a/src/include/access/tableam.h b/src/include/access/tableam.h
index 3fb184717f..996e99a5f9 100644
--- a/src/include/access/tableam.h
+++ b/src/include/access/tableam.h
@@ -526,7 +526,8 @@ typedef struct TableAmRoutine
bool wait,
TM_FailureData *tmfd,
LockTupleMode *lockmode,
- bool *update_indexes);
+ bool *update_indexes,
+ bool force_visibility);
/* see table_tuple_lock() for reference about parameters */
TM_Result (*tuple_lock) (Relation rel,
@@ -1506,12 +1507,12 @@ static inline TM_Result
table_tuple_update(Relation rel, ItemPointer otid, TupleTableSlot *slot,
CommandId cid, Snapshot snapshot, Snapshot crosscheck,
bool wait, TM_FailureData *tmfd, LockTupleMode *lockmode,
- bool *update_indexes)
+ bool *update_indexes, bool force_visibility)
{
return rel->rd_tableam->tuple_update(rel, otid, slot,
cid, snapshot, crosscheck,
wait, tmfd,
- lockmode, update_indexes);
+ lockmode, update_indexes, force_visibility);
}
/*
diff --git a/src/test/regress/expected/constraints.out b/src/test/regress/expected/constraints.out
index e6f6602d95..226b3a133e 100644
--- a/src/test/regress/expected/constraints.out
+++ b/src/test/regress/expected/constraints.out
@@ -429,21 +429,21 @@ 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) DO UPDATE SET t = 'five-upsert-update';
INSERT INTO UNIQUE_TBL VALUES (6, 'six-upsert-insert') ON CONFLICT (i) DO UPDATE SET t = 'six-upsert-update';
--- should fail
-INSERT INTO UNIQUE_TBL VALUES (1, 'a'), (2, 'b'), (2, 'b') ON CONFLICT (i) DO UPDATE SET t = 'fails';
-ERROR: ON CONFLICT DO UPDATE command cannot affect row a second time
-HINT: Ensure that no rows proposed for insertion within the same command have duplicate constrained values.
+-- should not fail
+INSERT INTO UNIQUE_TBL VALUES (11, 'a'), (22, 'b'), (22, 'b') ON CONFLICT (i) DO UPDATE SET t = 'fails';
SELECT * FROM UNIQUE_TBL;
- i | t
----+--------------------
- 1 | one
- 2 | two
- 4 | four
- | six
- | seven
- 5 | five-upsert-update
- 6 | six-upsert-insert
-(7 rows)
+ i | t
+----+--------------------
+ 1 | one
+ 2 | two
+ 4 | four
+ | six
+ | seven
+ 5 | five-upsert-update
+ 6 | six-upsert-insert
+ 11 | a
+ 22 | fails
+(9 rows)
DROP TABLE UNIQUE_TBL;
CREATE TABLE UNIQUE_TBL (i int UNIQUE NULLS NOT DISTINCT, t text);
diff --git a/src/test/regress/expected/insert_conflict.out b/src/test/regress/expected/insert_conflict.out
index 9e9e3bd00c..773981a322 100644
--- a/src/test/regress/expected/insert_conflict.out
+++ b/src/test/regress/expected/insert_conflict.out
@@ -700,19 +700,13 @@ begin transaction isolation level serializable;
insert into selfconflict values (3,1), (3,2) on conflict do nothing;
commit;
begin transaction isolation level read committed;
-insert into selfconflict values (4,1), (4,2) on conflict(f1) do update set f2 = 0;
-ERROR: ON CONFLICT DO UPDATE command cannot affect row a second time
-HINT: Ensure that no rows proposed for insertion within the same command have duplicate constrained values.
+insert into selfconflict values (4,1), (4,2) on conflict(f1) do update set f2 = -1;
commit;
begin transaction isolation level repeatable read;
-insert into selfconflict values (5,1), (5,2) on conflict(f1) do update set f2 = 0;
-ERROR: ON CONFLICT DO UPDATE command cannot affect row a second time
-HINT: Ensure that no rows proposed for insertion within the same command have duplicate constrained values.
+insert into selfconflict values (5,1), (5,2) on conflict(f1) do update set f2 = -2;
commit;
begin transaction isolation level serializable;
-insert into selfconflict values (6,1), (6,2) on conflict(f1) do update set f2 = 0;
-ERROR: ON CONFLICT DO UPDATE command cannot affect row a second time
-HINT: Ensure that no rows proposed for insertion within the same command have duplicate constrained values.
+insert into selfconflict values (6,1), (6,2) on conflict(f1) do update set f2 = -3;
commit;
select * from selfconflict;
f1 | f2
@@ -720,7 +714,10 @@ select * from selfconflict;
1 | 1
2 | 1
3 | 1
-(3 rows)
+ 4 | -1
+ 5 | -2
+ 6 | -3
+(6 rows)
drop table selfconflict;
-- check ON CONFLICT handling with partitioned tables
diff --git a/src/test/regress/sql/constraints.sql b/src/test/regress/sql/constraints.sql
index 5ffcd4ffc7..f5bc7b096a 100644
--- a/src/test/regress/sql/constraints.sql
+++ b/src/test/regress/sql/constraints.sql
@@ -299,8 +299,8 @@ INSERT INTO UNIQUE_TBL (t) VALUES ('seven');
INSERT INTO UNIQUE_TBL VALUES (5, 'five-upsert-insert') ON CONFLICT (i) DO UPDATE SET t = 'five-upsert-update';
INSERT INTO UNIQUE_TBL VALUES (6, 'six-upsert-insert') ON CONFLICT (i) DO UPDATE SET t = 'six-upsert-update';
--- should fail
-INSERT INTO UNIQUE_TBL VALUES (1, 'a'), (2, 'b'), (2, 'b') ON CONFLICT (i) DO UPDATE SET t = 'fails';
+-- should not fail
+INSERT INTO UNIQUE_TBL VALUES (11, 'a'), (22, 'b'), (22, 'b') ON CONFLICT (i) DO UPDATE SET t = 'fails';
SELECT * FROM UNIQUE_TBL;
diff --git a/src/test/regress/sql/insert_conflict.sql b/src/test/regress/sql/insert_conflict.sql
index 23d5778b82..42c5f6c778 100644
--- a/src/test/regress/sql/insert_conflict.sql
+++ b/src/test/regress/sql/insert_conflict.sql
@@ -434,15 +434,15 @@ insert into selfconflict values (3,1), (3,2) on conflict do nothing;
commit;
begin transaction isolation level read committed;
-insert into selfconflict values (4,1), (4,2) on conflict(f1) do update set f2 = 0;
+insert into selfconflict values (4,1), (4,2) on conflict(f1) do update set f2 = -1;
commit;
begin transaction isolation level repeatable read;
-insert into selfconflict values (5,1), (5,2) on conflict(f1) do update set f2 = 0;
+insert into selfconflict values (5,1), (5,2) on conflict(f1) do update set f2 = -2;
commit;
begin transaction isolation level serializable;
-insert into selfconflict values (6,1), (6,2) on conflict(f1) do update set f2 = 0;
+insert into selfconflict values (6,1), (6,2) on conflict(f1) do update set f2 = -3;
commit;
select * from selfconflict;
--
2.39.1
Hi,
On 2023-01-25 18:45:12 +0300, Aleksander Alekseev wrote:
Currently we allow self-conflicting inserts for ON CONFLICT DO NOTHING:
```
CREATE TABLE t (a INT UNIQUE, b INT);
INSERT INTO t VALUES (1,1), (1,2) ON CONFLICT DO NOTHING;
-- succeeds, inserting the first row and ignoring the second
```
... but not for ON CONFLICT .. DO UPDATE:```
INSERT INTO t VALUES (1,1), (1,2) ON CONFLICT (a) DO UPDATE SET b = 0;
ERROR: ON CONFLICT DO UPDATE command cannot affect row a second time
HINT: Ensure that no rows proposed for insertion within the same
command have duplicate constrained values.
```Tom pointed out in 2016 that this is actually a bug [1] and I agree.
I don't think I agree with this being a bug.
We can't sensible implement updating a row twice within a statement - hence
erroring out for ON CONFLICT DO UPDATE affecting a row twice. But what's the
justification for erroring out in the DO NOTHING case? ISTM that it's useful
to be able to handle such duplicates, and I don't immediately see what
semantic confusion or implementation difficulty we avoid by erroring out.
It seems somewhat likely that a behavioural change will cause trouble for some
of the uses of DO NOTHING out there.
Greetings,
Andres Freund
Hi Andres,
I don't think I agree with this being a bug.
Perhaps that's not a bug especially considering the fact that the
documentation describes this behavior, but in any case the fact that:
```
INSERT INTO t VALUES (1,1) ON CONFLICT (a) DO UPDATE SET b = 0;
INSERT INTO t VALUES (1,2) ON CONFLICT (a) DO UPDATE SET b = 0;
```
and:
```
INSERT INTO t VALUES (1,1), (1,2) ON CONFLICT (a) DO NOTHING;
``
.. both work, and:
```
INSERT INTO t VALUES (1,1), (1,2) ON CONFLICT (a) DO UPDATE SET b = 0;
```
... doesn't is rather confusing. There is no reason why the latest
query shouldn't work except for a slight complication of the code.
Which seems to be a reasonable tradeoff, for me at least.
But what's the justification for erroring out in the DO NOTHING case?
[...]
It seems somewhat likely that a behavioural change will cause trouble for some
of the uses of DO NOTHING out there.
Just to make sure we are on the same page. The patch doesn't break the
current DO NOTHING behavior but rather makes DO UPDATE work the same
way DO NOTHING does.
--
Best regards,
Aleksander Alekseev
On Wed, Jan 25, 2023 at 11:01 AM Aleksander Alekseev
<aleksander@timescale.com> wrote:
Just to make sure we are on the same page. The patch doesn't break the
current DO NOTHING behavior but rather makes DO UPDATE work the same
way DO NOTHING does.
It also makes DO UPDATE not work the same way as either UPDATE itself
(which will silently skip a second or subsequent update of the same
row by the same UPDATE statement in RC mode), or MERGE (which has
similar cardinality violations).
DO NOTHING doesn't lock any conflicting row, and so won't have to
dirty pages that have matching rows. It was always understood to be
more susceptible to certain issues (when in READ COMMITTED mode) as a
result. There are some halfway reasonable arguments against this sort
of behavior, but I believe that we made the right trade-off.
--
Peter Geoghegan
Hi Peter,
It also makes DO UPDATE not work the same way as either UPDATE itself
(which will silently skip a second or subsequent update of the same
row by the same UPDATE statement in RC mode), or MERGE (which has
similar cardinality violations).
That's true. On the flip side, UPDATE and MERGE are different
statements and arguably shouldn't behave the same way INSERT does.
To clarify, I'm merely proposing the change and playing the role of
Devil's advocate here. I'm not arguing that the patch should be
necessarily accepted. In the end of the day it's up to the community
to decide. Personally I think it would make the users a bit happier.
The actual reason why I made the patch is that a colleague of mine,
Sven Klemm, encountered this limitation recently and was puzzled by it
and so was I. The only workaround the user currently has is to execute
several INSERTs one by one which is expensive when you have a lot of
INSERTs.
--
Best regards,
Aleksander Alekseev
Hi,
On 2023-01-25 22:00:50 +0300, Aleksander Alekseev wrote:
Perhaps that's not a bug especially considering the fact that the
documentation describes this behavior, but in any case the fact that:```
INSERT INTO t VALUES (1,1) ON CONFLICT (a) DO UPDATE SET b = 0;
INSERT INTO t VALUES (1,2) ON CONFLICT (a) DO UPDATE SET b = 0;
```and:
```
INSERT INTO t VALUES (1,1), (1,2) ON CONFLICT (a) DO NOTHING;
``.. both work, and:
```
INSERT INTO t VALUES (1,1), (1,2) ON CONFLICT (a) DO UPDATE SET b = 0;
```... doesn't is rather confusing. There is no reason why the latest
query shouldn't work except for a slight complication of the code.
Which seems to be a reasonable tradeoff, for me at least.
I don't agree that this is just about a "slight complication" of the code. I
think semantically the proposed new behaviour is pretty bogus.
It *certainly* can't be right to just continue with the update in heap_update,
as you've done. You'd have to skip the update, not execute it. What am I
missing here?
I think this'd completely break triggers, for example, because they won't be
able to get the prior row version, since it won't actually be a row ever
visible (due to cmin=cmax).
I suspect it might break unique constraints as well, because we'd end up with
an invisible row in part of the ctid chain.
But what's the justification for erroring out in the DO NOTHING case?
[...]
It seems somewhat likely that a behavioural change will cause trouble for some
of the uses of DO NOTHING out there.Just to make sure we are on the same page. The patch doesn't break the
current DO NOTHING behavior but rather makes DO UPDATE work the same
way DO NOTHING does.
I see that now - I somehow thought you were recommending to error out in both
cases, rather than the other way round.
Greetings,
Andres Freund
Hi Andres,
It *certainly* can't be right to just continue with the update in heap_update,
I see no reason why. What makes this case so different from updating a
tuple created by the previous command?
as you've done. You'd have to skip the update, not execute it. What am I
missing here?
Simply skipping updates in a statement that literally says DO UPDATE
doesn't seem to be the behavior a user would expect.
I think this'd completely break triggers, for example, because they won't be
able to get the prior row version, since it won't actually be a row ever
visible (due to cmin=cmax).I suspect it might break unique constraints as well, because we'd end up with
an invisible row in part of the ctid chain.
That's a reasonable concern, however I was unable to break unique
constraints or triggers so far:
```
CREATE TABLE t (a INT UNIQUE, b INT);
CREATE OR REPLACE FUNCTION t_insert() RETURNS TRIGGER AS $$
BEGIN
RAISE NOTICE 't_insert triggered: new = %, old = %', NEW, OLD;
RETURN NULL;
END
$$ LANGUAGE 'plpgsql';
CREATE OR REPLACE FUNCTION t_update() RETURNS TRIGGER AS $$
BEGIN
RAISE NOTICE 't_update triggered: new = %, old = %', NEW, OLD;
RETURN NULL;
END
$$ LANGUAGE 'plpgsql';
CREATE TRIGGER t_insert_trigger
AFTER INSERT ON t
FOR EACH ROW EXECUTE PROCEDURE t_insert();
CREATE TRIGGER t_insert_update
AFTER UPDATE ON t
FOR EACH ROW EXECUTE PROCEDURE t_update();
INSERT INTO t VALUES (1,1), (1,2) ON CONFLICT (a) DO UPDATE SET b = 0;
NOTICE: t_insert triggered: new = (1,1), old = <NULL>
NOTICE: t_update triggered: new = (1,0), old = (1,1)
INSERT INTO t VALUES (2,1), (2,2), (3,1) ON CONFLICT (a) DO UPDATE SET b = 0;
NOTICE: t_insert triggered: new = (2,1), old = <NULL>
NOTICE: t_update triggered: new = (2,0), old = (2,1)
NOTICE: t_insert triggered: new = (3,1), old = <NULL>
=# SELECT * FROM t;
a | b
---+---
1 | 0
2 | 0
3 | 1
```
PFA patch v2 that also includes the test shown above.
Are there any other scenarios we should check?
--
Best regards,
Aleksander Alekseev
Attachments:
v2-0001-Make-ON-CONFLICT-DO-NOTHING-and-ON-CONFLICT-DO-UP.patchapplication/octet-stream; name=v2-0001-Make-ON-CONFLICT-DO-NOTHING-and-ON-CONFLICT-DO-UP.patchDownload
From 122493c8d197fa7ccd58de984b6bb0b2374c0b7d Mon Sep 17 00:00:00 2001
From: Aleksander Alekseev <aleksander@timescale.com>
Date: Wed, 25 Jan 2023 15:59:35 +0300
Subject: [PATCH v2] Make ON CONFLICT DO NOTHING and ON CONFLICT DO UPDATE
consistent
Prior to this commit we allowed self-conflicting inserts for DO NOTHING:
CREATE TABLE t (a INT UNIQUE, b INT);
INSERT INTO t VALUES (1,1), (1,2) ON CONFLICT DO NOTHING;
-- succeeds, inserting the first row and ignoring the second
... but not for DO UPDATE:
INSERT INTO t VALUES (1,1), (1,2) ON CONFLICT (a) DO UPDATE SET b = 0;
ERROR: ON CONFLICT DO UPDATE command cannot affect row a second time
Now DO UPDATE is handled similarly to DO NOTHING.
Author: Aleksander Alekseev
Reviewed-by: Andres Freund, TODO FIXME
Discussion: https://postgr.es/m/CAJ7c6TPQJNFETz9H_qPpA3x7ybz2D1QMDtBku_iK33gT3UR34Q%40mail.gmail.com
---
doc/src/sgml/ref/insert.sgml | 4 +-
src/backend/access/heap/heapam.c | 20 ++++++++-
src/backend/access/heap/heapam_handler.c | 4 +-
src/backend/access/table/tableam.c | 3 +-
src/backend/executor/nodeModifyTable.c | 43 ++++++++----------
src/include/access/heapam.h | 3 +-
src/include/access/tableam.h | 7 +--
src/test/regress/expected/constraints.out | 28 ++++++------
src/test/regress/expected/insert_conflict.out | 45 ++++++++++++++-----
src/test/regress/sql/constraints.sql | 4 +-
src/test/regress/sql/insert_conflict.sql | 37 +++++++++++++--
11 files changed, 133 insertions(+), 65 deletions(-)
diff --git a/doc/src/sgml/ref/insert.sgml b/doc/src/sgml/ref/insert.sgml
index 7cea70329e..368e6f5bd6 100644
--- a/doc/src/sgml/ref/insert.sgml
+++ b/doc/src/sgml/ref/insert.sgml
@@ -531,9 +531,7 @@ INSERT INTO <replaceable class="parameter">table_name</replaceable> [ AS <replac
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 an
- arbiter index or constraint.
+ when this situation arises.
</para>
<para>
diff --git a/src/backend/access/heap/heapam.c b/src/backend/access/heap/heapam.c
index e6024a980b..37a3be7f09 100644
--- a/src/backend/access/heap/heapam.c
+++ b/src/backend/access/heap/heapam.c
@@ -3129,7 +3129,7 @@ simple_heap_delete(Relation relation, ItemPointer tid)
TM_Result
heap_update(Relation relation, ItemPointer otid, HeapTuple newtup,
CommandId cid, Snapshot crosscheck, bool wait,
- TM_FailureData *tmfd, LockTupleMode *lockmode)
+ TM_FailureData *tmfd, LockTupleMode *lockmode, bool force_visibility)
{
TM_Result result;
TransactionId xid = GetCurrentTransactionId();
@@ -3299,6 +3299,21 @@ l2:
locker_remains = false;
result = HeapTupleSatisfiesUpdate(&oldtup, cid, buffer);
+ if (force_visibility && (result == TM_Invisible))
+ {
+ /*
+ * Special case of ON CONFLICT .. DO UPDATE with conflicting tuples
+ * created within the same command. Normally a command doesn't see the
+ * tuples created by this command e.g. to avoid Halloween problem.
+ * However in this particular case we want to treat the tuples as if
+ * they were inserted by the previosly executed command.
+ *
+ * This is done in order to make the behavior consistent with ON
+ * CONFLICT .. DO NOTHING.
+ */
+ result = TM_Ok;
+ }
+
/* see below about the "no wait" case */
Assert(result != TM_BeingModified || wait);
@@ -3457,6 +3472,7 @@ l2:
LockBuffer(buffer, BUFFER_LOCK_UNLOCK);
heap_acquire_tuplock(relation, &(oldtup.t_self), *lockmode,
LockWaitBlock, &have_tuple_lock);
+
XactLockTableWait(xwait, relation, &oldtup.t_self,
XLTW_Update);
checked_lockers = true;
@@ -4174,7 +4190,7 @@ simple_heap_update(Relation relation, ItemPointer otid, HeapTuple tup)
result = heap_update(relation, otid, tup,
GetCurrentCommandId(true), InvalidSnapshot,
true /* wait for commit */ ,
- &tmfd, &lockmode);
+ &tmfd, &lockmode, false);
switch (result)
{
case TM_SelfModified:
diff --git a/src/backend/access/heap/heapam_handler.c b/src/backend/access/heap/heapam_handler.c
index c4b1916d36..001addd780 100644
--- a/src/backend/access/heap/heapam_handler.c
+++ b/src/backend/access/heap/heapam_handler.c
@@ -314,7 +314,7 @@ static TM_Result
heapam_tuple_update(Relation relation, ItemPointer otid, TupleTableSlot *slot,
CommandId cid, Snapshot snapshot, Snapshot crosscheck,
bool wait, TM_FailureData *tmfd,
- LockTupleMode *lockmode, bool *update_indexes)
+ LockTupleMode *lockmode, bool *update_indexes, bool force_visibility)
{
bool shouldFree = true;
HeapTuple tuple = ExecFetchSlotHeapTuple(slot, true, &shouldFree);
@@ -325,7 +325,7 @@ heapam_tuple_update(Relation relation, ItemPointer otid, TupleTableSlot *slot,
tuple->t_tableOid = slot->tts_tableOid;
result = heap_update(relation, otid, tuple, cid, crosscheck, wait,
- tmfd, lockmode);
+ tmfd, lockmode, force_visibility);
ItemPointerCopy(&tuple->t_self, &slot->tts_tid);
/*
diff --git a/src/backend/access/table/tableam.c b/src/backend/access/table/tableam.c
index ef0d34fcee..065c8e9e74 100644
--- a/src/backend/access/table/tableam.c
+++ b/src/backend/access/table/tableam.c
@@ -355,7 +355,8 @@ simple_table_tuple_update(Relation rel, ItemPointer otid,
GetCurrentCommandId(true),
snapshot, InvalidSnapshot,
true /* wait for commit */ ,
- &tmfd, &lockmode, update_indexes);
+ &tmfd, &lockmode, update_indexes,
+ false /* don't force visibility */ );
switch (result)
{
diff --git a/src/backend/executor/nodeModifyTable.c b/src/backend/executor/nodeModifyTable.c
index f419c47065..2baf1ea7f5 100644
--- a/src/backend/executor/nodeModifyTable.c
+++ b/src/backend/executor/nodeModifyTable.c
@@ -1955,7 +1955,7 @@ ExecUpdatePrepareSlot(ResultRelInfo *resultRelInfo,
static TM_Result
ExecUpdateAct(ModifyTableContext *context, ResultRelInfo *resultRelInfo,
ItemPointer tupleid, HeapTuple oldtuple, TupleTableSlot *slot,
- bool canSetTag, UpdateContext *updateCxt)
+ bool canSetTag, UpdateContext *updateCxt, bool force_visibility)
{
EState *estate = context->estate;
Relation resultRelationDesc = resultRelInfo->ri_RelationDesc;
@@ -2089,7 +2089,7 @@ lreplace:
estate->es_crosscheck_snapshot,
true /* wait for commit */ ,
&context->tmfd, &updateCxt->lockmode,
- &updateCxt->updateIndexes);
+ &updateCxt->updateIndexes, force_visibility);
if (result == TM_Ok)
updateCxt->updated = true;
@@ -2240,7 +2240,7 @@ ExecCrossPartitionUpdateForeignKey(ModifyTableContext *context,
static TupleTableSlot *
ExecUpdate(ModifyTableContext *context, ResultRelInfo *resultRelInfo,
ItemPointer tupleid, HeapTuple oldtuple, TupleTableSlot *slot,
- bool canSetTag)
+ bool canSetTag, bool force_visibility)
{
EState *estate = context->estate;
Relation resultRelationDesc = resultRelInfo->ri_RelationDesc;
@@ -2298,7 +2298,7 @@ ExecUpdate(ModifyTableContext *context, ResultRelInfo *resultRelInfo,
redo_act:
result = ExecUpdateAct(context, resultRelInfo, tupleid, oldtuple, slot,
- canSetTag, &updateCxt);
+ canSetTag, &updateCxt, force_visibility);
/*
* If ExecUpdateAct reports that a cross-partition update was done,
@@ -2496,6 +2496,9 @@ ExecOnConflictUpdate(ModifyTableContext *context,
TransactionId xmin;
bool isnull;
+ /* Is this a case of conflicting tuples created within the same command? */
+ bool conflict_within_command = false;
+
/* Determine lock mode to use */
lockmode = ExecUpdateLockMode(context->estate, resultRelInfo);
@@ -2522,17 +2525,6 @@ ExecOnConflictUpdate(ModifyTableContext *context,
* This can occur when a just inserted tuple is updated again in
* the same command. E.g. because multiple rows with the same
* conflicting key values are inserted.
- *
- * This is somewhat similar to the ExecUpdate() TM_SelfModified
- * case. We do not want to proceed because it would lead to the
- * same row being updated a second time in some unspecified order,
- * and in contrast to plain UPDATEs there's no historical behavior
- * to break.
- *
- * It is the user's responsibility to prevent this situation from
- * occurring. These problems are why the SQL standard similarly
- * specifies that for SQL MERGE, an exception must be raised in
- * the event of an attempt to update the same row twice.
*/
xminDatum = slot_getsysattr(existing,
MinTransactionIdAttributeNumber,
@@ -2541,12 +2533,14 @@ ExecOnConflictUpdate(ModifyTableContext *context,
xmin = DatumGetTransactionId(xminDatum);
if (TransactionIdIsCurrentTransactionId(xmin))
- ereport(ERROR,
- (errcode(ERRCODE_CARDINALITY_VIOLATION),
- /* translator: %s is a SQL command name */
- errmsg("%s command cannot affect row a second time",
- "ON CONFLICT DO UPDATE"),
- errhint("Ensure that no rows proposed for insertion within the same command have duplicate constrained values.")));
+ {
+ /*
+ * Detect the case of ON CONFLICT .. DO UPDATE .. with
+ * conflicting tuples created within the same command.
+ */
+ conflict_within_command = true;
+ break;
+ }
/* This shouldn't happen */
elog(ERROR, "attempted to lock invisible tuple");
@@ -2674,7 +2668,7 @@ ExecOnConflictUpdate(ModifyTableContext *context,
*returning = ExecUpdate(context, resultRelInfo,
conflictTid, NULL,
resultRelInfo->ri_onConflict->oc_ProjSlot,
- canSetTag);
+ canSetTag, conflict_within_command);
/*
* Clear out existing tuple, as there might not be another conflict among
@@ -2881,7 +2875,8 @@ lmerge_matched:
}
ExecUpdatePrepareSlot(resultRelInfo, newslot, context->estate);
result = ExecUpdateAct(context, resultRelInfo, tupleid, NULL,
- newslot, mtstate->canSetTag, &updateCxt);
+ newslot, mtstate->canSetTag, &updateCxt,
+ false);
if (result == TM_Ok && updateCxt.updated)
{
ExecUpdateEpilogue(context, &updateCxt, resultRelInfo,
@@ -3847,7 +3842,7 @@ ExecModifyTable(PlanState *pstate)
/* Now apply the update. */
slot = ExecUpdate(&context, resultRelInfo, tupleid, oldtuple,
- slot, node->canSetTag);
+ slot, node->canSetTag, false);
break;
case CMD_DELETE:
diff --git a/src/include/access/heapam.h b/src/include/access/heapam.h
index 417108f1e0..023aeff1a6 100644
--- a/src/include/access/heapam.h
+++ b/src/include/access/heapam.h
@@ -249,7 +249,8 @@ extern void heap_abort_speculative(Relation relation, ItemPointer tid);
extern TM_Result heap_update(Relation relation, ItemPointer otid,
HeapTuple newtup,
CommandId cid, Snapshot crosscheck, bool wait,
- struct TM_FailureData *tmfd, LockTupleMode *lockmode);
+ struct TM_FailureData *tmfd, LockTupleMode *lockmode,
+ bool force_visibility);
extern TM_Result heap_lock_tuple(Relation relation, HeapTuple tuple,
CommandId cid, LockTupleMode mode, LockWaitPolicy wait_policy,
bool follow_updates,
diff --git a/src/include/access/tableam.h b/src/include/access/tableam.h
index 3fb184717f..996e99a5f9 100644
--- a/src/include/access/tableam.h
+++ b/src/include/access/tableam.h
@@ -526,7 +526,8 @@ typedef struct TableAmRoutine
bool wait,
TM_FailureData *tmfd,
LockTupleMode *lockmode,
- bool *update_indexes);
+ bool *update_indexes,
+ bool force_visibility);
/* see table_tuple_lock() for reference about parameters */
TM_Result (*tuple_lock) (Relation rel,
@@ -1506,12 +1507,12 @@ static inline TM_Result
table_tuple_update(Relation rel, ItemPointer otid, TupleTableSlot *slot,
CommandId cid, Snapshot snapshot, Snapshot crosscheck,
bool wait, TM_FailureData *tmfd, LockTupleMode *lockmode,
- bool *update_indexes)
+ bool *update_indexes, bool force_visibility)
{
return rel->rd_tableam->tuple_update(rel, otid, slot,
cid, snapshot, crosscheck,
wait, tmfd,
- lockmode, update_indexes);
+ lockmode, update_indexes, force_visibility);
}
/*
diff --git a/src/test/regress/expected/constraints.out b/src/test/regress/expected/constraints.out
index e6f6602d95..3641dc571a 100644
--- a/src/test/regress/expected/constraints.out
+++ b/src/test/regress/expected/constraints.out
@@ -429,21 +429,21 @@ 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) DO UPDATE SET t = 'five-upsert-update';
INSERT INTO UNIQUE_TBL VALUES (6, 'six-upsert-insert') ON CONFLICT (i) DO UPDATE SET t = 'six-upsert-update';
--- should fail
-INSERT INTO UNIQUE_TBL VALUES (1, 'a'), (2, 'b'), (2, 'b') ON CONFLICT (i) DO UPDATE SET t = 'fails';
-ERROR: ON CONFLICT DO UPDATE command cannot affect row a second time
-HINT: Ensure that no rows proposed for insertion within the same command have duplicate constrained values.
+-- should not fail
+INSERT INTO UNIQUE_TBL VALUES (11, 'a'), (22, 'b'), (22, 'b') ON CONFLICT (i) DO UPDATE SET t = 'success';
SELECT * FROM UNIQUE_TBL;
- i | t
----+--------------------
- 1 | one
- 2 | two
- 4 | four
- | six
- | seven
- 5 | five-upsert-update
- 6 | six-upsert-insert
-(7 rows)
+ i | t
+----+--------------------
+ 1 | one
+ 2 | two
+ 4 | four
+ | six
+ | seven
+ 5 | five-upsert-update
+ 6 | six-upsert-insert
+ 11 | a
+ 22 | success
+(9 rows)
DROP TABLE UNIQUE_TBL;
CREATE TABLE UNIQUE_TBL (i int UNIQUE NULLS NOT DISTINCT, t text);
diff --git a/src/test/regress/expected/insert_conflict.out b/src/test/regress/expected/insert_conflict.out
index 9e9e3bd00c..f22a54ce0e 100644
--- a/src/test/regress/expected/insert_conflict.out
+++ b/src/test/regress/expected/insert_conflict.out
@@ -700,19 +700,13 @@ begin transaction isolation level serializable;
insert into selfconflict values (3,1), (3,2) on conflict do nothing;
commit;
begin transaction isolation level read committed;
-insert into selfconflict values (4,1), (4,2) on conflict(f1) do update set f2 = 0;
-ERROR: ON CONFLICT DO UPDATE command cannot affect row a second time
-HINT: Ensure that no rows proposed for insertion within the same command have duplicate constrained values.
+insert into selfconflict values (4,1), (4,2) on conflict(f1) do update set f2 = -1;
commit;
begin transaction isolation level repeatable read;
-insert into selfconflict values (5,1), (5,2) on conflict(f1) do update set f2 = 0;
-ERROR: ON CONFLICT DO UPDATE command cannot affect row a second time
-HINT: Ensure that no rows proposed for insertion within the same command have duplicate constrained values.
+insert into selfconflict values (5,1), (5,2) on conflict(f1) do update set f2 = -2;
commit;
begin transaction isolation level serializable;
-insert into selfconflict values (6,1), (6,2) on conflict(f1) do update set f2 = 0;
-ERROR: ON CONFLICT DO UPDATE command cannot affect row a second time
-HINT: Ensure that no rows proposed for insertion within the same command have duplicate constrained values.
+insert into selfconflict values (6,1), (6,2) on conflict(f1) do update set f2 = -3;
commit;
select * from selfconflict;
f1 | f2
@@ -720,9 +714,40 @@ select * from selfconflict;
1 | 1
2 | 1
3 | 1
-(3 rows)
+ 4 | -1
+ 5 | -2
+ 6 | -3
+(6 rows)
drop table selfconflict;
+-- check if self-conflicting INSERTs work with triggers
+create table t (a int unique, b int);
+create or replace function t_insert() returns trigger as $$
+begin
+ raise notice 't_insert triggered: new = %, old = %', new, old;
+ return null;
+end
+$$ language 'plpgsql';
+create or replace function t_update() returns trigger as $$
+begin
+ raise notice 't_update triggered: new = %, old = %', new, old;
+ return null;
+end
+$$ language 'plpgsql';
+create trigger t_insert_trigger
+after insert on t
+for each row execute procedure t_insert();
+create trigger t_insert_update
+after update on t
+for each row execute procedure t_update();
+insert into t values (1,1), (1,2) on conflict (a) do update set b = 0;
+NOTICE: t_insert triggered: new = (1,1), old = <NULL>
+NOTICE: t_update triggered: new = (1,0), old = (1,1)
+insert into t values (2,1), (2,2), (3,1) on conflict (a) do update set b = 0;
+NOTICE: t_insert triggered: new = (2,1), old = <NULL>
+NOTICE: t_update triggered: new = (2,0), old = (2,1)
+NOTICE: t_insert triggered: new = (3,1), old = <NULL>
+drop table t;
-- check ON CONFLICT handling with partitioned tables
create table parted_conflict_test (a int unique, b char) partition by list (a);
create table parted_conflict_test_1 partition of parted_conflict_test (b unique) for values in (1, 2);
diff --git a/src/test/regress/sql/constraints.sql b/src/test/regress/sql/constraints.sql
index 5ffcd4ffc7..c900d42a4a 100644
--- a/src/test/regress/sql/constraints.sql
+++ b/src/test/regress/sql/constraints.sql
@@ -299,8 +299,8 @@ INSERT INTO UNIQUE_TBL (t) VALUES ('seven');
INSERT INTO UNIQUE_TBL VALUES (5, 'five-upsert-insert') ON CONFLICT (i) DO UPDATE SET t = 'five-upsert-update';
INSERT INTO UNIQUE_TBL VALUES (6, 'six-upsert-insert') ON CONFLICT (i) DO UPDATE SET t = 'six-upsert-update';
--- should fail
-INSERT INTO UNIQUE_TBL VALUES (1, 'a'), (2, 'b'), (2, 'b') ON CONFLICT (i) DO UPDATE SET t = 'fails';
+-- should not fail
+INSERT INTO UNIQUE_TBL VALUES (11, 'a'), (22, 'b'), (22, 'b') ON CONFLICT (i) DO UPDATE SET t = 'success';
SELECT * FROM UNIQUE_TBL;
diff --git a/src/test/regress/sql/insert_conflict.sql b/src/test/regress/sql/insert_conflict.sql
index 23d5778b82..96054122a0 100644
--- a/src/test/regress/sql/insert_conflict.sql
+++ b/src/test/regress/sql/insert_conflict.sql
@@ -434,21 +434,52 @@ insert into selfconflict values (3,1), (3,2) on conflict do nothing;
commit;
begin transaction isolation level read committed;
-insert into selfconflict values (4,1), (4,2) on conflict(f1) do update set f2 = 0;
+insert into selfconflict values (4,1), (4,2) on conflict(f1) do update set f2 = -1;
commit;
begin transaction isolation level repeatable read;
-insert into selfconflict values (5,1), (5,2) on conflict(f1) do update set f2 = 0;
+insert into selfconflict values (5,1), (5,2) on conflict(f1) do update set f2 = -2;
commit;
begin transaction isolation level serializable;
-insert into selfconflict values (6,1), (6,2) on conflict(f1) do update set f2 = 0;
+insert into selfconflict values (6,1), (6,2) on conflict(f1) do update set f2 = -3;
commit;
select * from selfconflict;
drop table selfconflict;
+-- check if self-conflicting INSERTs work with triggers
+
+create table t (a int unique, b int);
+
+create or replace function t_insert() returns trigger as $$
+begin
+ raise notice 't_insert triggered: new = %, old = %', new, old;
+ return null;
+end
+$$ language 'plpgsql';
+
+create or replace function t_update() returns trigger as $$
+begin
+ raise notice 't_update triggered: new = %, old = %', new, old;
+ return null;
+end
+$$ language 'plpgsql';
+
+create trigger t_insert_trigger
+after insert on t
+for each row execute procedure t_insert();
+
+create trigger t_insert_update
+after update on t
+for each row execute procedure t_update();
+
+insert into t values (1,1), (1,2) on conflict (a) do update set b = 0;
+insert into t values (2,1), (2,2), (3,1) on conflict (a) do update set b = 0;
+
+drop table t;
+
-- check ON CONFLICT handling with partitioned tables
create table parted_conflict_test (a int unique, b char) partition by list (a);
create table parted_conflict_test_1 partition of parted_conflict_test (b unique) for values in (1, 2);
--
2.39.1
Hi,
On 2023-01-26 13:07:08 +0300, Aleksander Alekseev wrote:
It *certainly* can't be right to just continue with the update in heap_update,
I see no reason why. What makes this case so different from updating a
tuple created by the previous command?
To me it's a pretty fundamental violation of how heap visibility works. I'm
quite sure that there will be problems, but I don't feel like investing the
time to find a reproducer for something that I'm ready to reject on principle.
as you've done. You'd have to skip the update, not execute it. What am I
missing here?Simply skipping updates in a statement that literally says DO UPDATE
doesn't seem to be the behavior a user would expect.
Given that we skip the update in "UPDATE", your argument doesn't hold much
water.
I think this'd completely break triggers, for example, because they won't be
able to get the prior row version, since it won't actually be a row ever
visible (due to cmin=cmax).I suspect it might break unique constraints as well, because we'd end up with
an invisible row in part of the ctid chain.That's a reasonable concern, however I was unable to break unique
constraints or triggers so far:
I think you'd have to do a careful analysis of a lot of code for that to hold
any water.
I continue to think that we should just reject this behavioural change.
Greetings,
Andres Freund
Hi,
To me it's a pretty fundamental violation of how heap visibility works.
I don't think this has much to do with heap visibility. It's true that
generally a command doesn't see its own tuples. This is done in order
to avoid the Halloween problem which however can't happen in this
particular case.
Other than that the heap doesn't care about the visibility, it merely
stores the tuples. The visibility is determined by xmin/xmax, the
isolation level, etc.
It's true that the patch changes visibility rules in one very
particular edge case. This alone is arguably not a good enough reason
to reject a patch.
Given that we skip the update in "UPDATE", your argument doesn't hold much
water.
Peter made this argument above too and I will give the same anwer.
There is no reason why two completely different SQL statements should
behave the same.
That's a reasonable concern, however I was unable to break unique
constraints or triggers so far:I think you'd have to do a careful analysis of a lot of code for that to hold
any water.
Alternatively we could work smarter, not harder, and let the hardware
find the bugs for us. Writing tests is much simpler and bullet-proof
than analyzing the code.
Again, to clarify, I'm merely playing the role of Devil's advocate
here. I'm not saying that the patch should necessarily be accepted,
nor am I 100% sure that it has any undiscovered bugs. However the
arguments against received so far don't strike me personally as being
particularly convincing.
As an example, one could argue that there are applications that
*expect* to get an ERROR in the case of self-conflicting inserts. And
by changing this behavior we will break these applications. If the
majority believes that we seriously care about this it would be a good
enough reason to withdraw the patch.
--
Best regards,
Aleksander Alekseev
Hi,
On 2023-02-08 16:08:39 +0300, Aleksander Alekseev wrote:
To me it's a pretty fundamental violation of how heap visibility works.
I don't think this has much to do with heap visibility. It's true that
generally a command doesn't see its own tuples. This is done in order
to avoid the Halloween problem which however can't happen in this
particular case.Other than that the heap doesn't care about the visibility, it merely
stores the tuples. The visibility is determined by xmin/xmax, the
isolation level, etc.
Yes, and the fact is that cmin == cmax is something that we don't normally
produce, yet you emit it now, without, as far as I can tell it, a convincing
reason.
That's a reasonable concern, however I was unable to break unique
constraints or triggers so far:I think you'd have to do a careful analysis of a lot of code for that to hold
any water.Alternatively we could work smarter, not harder, and let the hardware
find the bugs for us. Writing tests is much simpler and bullet-proof
than analyzing the code.
That's a spectactularly wrong argument in almost all cases. Unless you have a
way to get to full branch coverage or use a model checker that basically does
the same, testing isn't going to give you a whole lot of confidence that you
haven't introduced bugs. This is particularly true for something like heapam,
where a lot of the tricky behaviour requires complicated interactions between
multiple connections.
Again, to clarify, I'm merely playing the role of Devil's advocate
here. I'm not saying that the patch should necessarily be accepted,
nor am I 100% sure that it has any undiscovered bugs. However the
arguments against received so far don't strike me personally as being
particularly convincing.
I've said my piece, as-is I vote to reject the patch.
Greetings,
Andres Freund
On Wed, Feb 8, 2023 at 5:08 AM Aleksander Alekseev
<aleksander@timescale.com> wrote:
To me it's a pretty fundamental violation of how heap visibility works.
I don't think this has much to do with heap visibility. It's true that
generally a command doesn't see its own tuples. This is done in order
to avoid the Halloween problem which however can't happen in this
particular case.Other than that the heap doesn't care about the visibility, it merely
stores the tuples. The visibility is determined by xmin/xmax, the
isolation level, etc.
I think that in a green field situation we would probably make READ
COMMITTED updates throw cardinality violations in the same way as ON
CONFLICT DO UPDATE, while not changing anything about ON CONFLICT DO
NOTHING. We made a deliberate trade-off with the design of DO NOTHING,
which won't lock conflicting rows, and so won't dirty any heap pages
that it doesn't insert on to.
I don't buy your argument about DO UPDATE needing to be brought into
line with DO NOTHING. In any case I'm pretty sure that Tom's remarks
in 2016 about a behavioral inconsistencies (which you cited) actually
called for making DO NOTHING more like DO UPDATE -- not the other way
around.
To me it seems as if allowing the same command to update the same row
more than once is just not desirable in general. It doesn't seem
necessary to bring low level arguments about cmin/cmax into it, nor
does it seem necessary to talk about things like the Halloween
problem. To me the best argument is also the simplest: who would want
us to allow it, and for what purpose?
I suppose that we might theoretically prefer to throw a cardinality
violation for DO NOTHING, but I don't see a way to do that without
locking rows and dirtying heap pages. If somebody were to argue that
we should make DO NOTHING lock rows and throw similar errors now then
I'd also disagree with them, but to a much lesser degree. I don't
think that this patch is a good idea.
--
Peter Geoghegan
Hi,
Yes, and the fact is that cmin == cmax is something that we don't normally
produce
Not sure if this is particularly relevant to this discussion but I
can't resist noticing that the heap doesn't even store cmin and
cmax... There is only HeapTupleHeaderData.t_cid and flags. cmin/cmax
are merely smoke and mirrors we use to trick a user.
And yes, the patch doesn't seem to break much mirrors:
```
=# create table t (a int unique, b int);
=# insert into t values (1,1), (1,2) on conflict (a) do update set b = 0;
=# SELECT xmin, xmax, cmin, cmax, * FROM t;
xmin | xmax | cmin | cmax | a | b
------+------+------+------+---+---
731 | 0 | 0 | 0 | 1 | 0
=# begin;
=# insert into t values (2,1), (2,2), (3,1) on conflict (a) do update set b = 0;
=# SELECT xmin, xmax, cmin, cmax, * FROM t;
xmin | xmax | cmin | cmax | a | b
------+------+------+------+---+---
731 | 0 | 0 | 0 | 1 | 0
732 | 0 | 0 | 0 | 2 | 0
732 | 0 | 0 | 0 | 3 | 1
=# insert into t values (2,1), (2,2), (3,1) on conflict (a) do update set b = 0;
=# SELECT xmin, xmax, cmin, cmax, * FROM t;
xmin | xmax | cmin | cmax | a | b
------+------+------+------+---+---
731 | 0 | 0 | 0 | 1 | 0
732 | 732 | 1 | 1 | 2 | 0
732 | 732 | 1 | 1 | 3 | 0
=# commit;
=# SELECT xmin, xmax, cmin, cmax, * FROM t;
xmin | xmax | cmin | cmax | a | b
------+------+------+------+---+---
731 | 0 | 0 | 0 | 1 | 0
732 | 732 | 1 | 1 | 2 | 0
732 | 732 | 1 | 1 | 3 | 0
```
That's a spectactularly wrong argument in almost all cases. Unless you have a
way to get to full branch coverage or use a model checker that basically does
the same, testing isn't going to give you a whole lot of confidence that you
haven't introduced bugs.
But neither will reviewing a lot of code...
I've said my piece, as-is I vote to reject the patch.
Fair enough. I'm merely saying that rejecting a patch because it
doesn't include a TLA+ model is something novel :)
I don't buy your argument about DO UPDATE needing to be brought into
line with DO NOTHING. In any case I'm pretty sure that Tom's remarks
in 2016 about a behavioral inconsistencies (which you cited) actually
called for making DO NOTHING more like DO UPDATE -- not the other way
around.
Interesting. Yep, we could use a bit of input from Tom on this one.
This of course would break backward compatibility. But we can always
invent something like:
```
INSERT INTO ..
ON CONFLICT DO [NOTHING|UPDATE .. ]
[ALLOWING|FORBIDDING] SELF CONFLICTS;
```
... if we really want to.
problem. To me the best argument is also the simplest: who would want
us to allow it, and for what purpose?
Good question.
This arguably has little use for application developers. As an
application developer you typically know your unique constraints and
using this knowledge you can rewrite the query as needed and add any
other accompanying logic.
However, extension developers, as an example, often don't know the
underlying unique constraints (more specifically, it's difficult to
look for them and process them manually) and often have to process any
garbage the application developer passes to an extension.
This of course is applicable not only to extensions, but to any
middleware between the DBMS and the application.
--
Best regards,
Aleksander Alekseev
Hi,
```
=# commit;
=# SELECT xmin, xmax, cmin, cmax, * FROM t;
xmin | xmax | cmin | cmax | a | b
------+------+------+------+---+---
731 | 0 | 0 | 0 | 1 | 0
732 | 732 | 1 | 1 | 2 | 0
732 | 732 | 1 | 1 | 3 | 0
```
Oops, you got me :) This of course isn't right - the xmax transaction
is committed but we still see the data, etc.
If we really are going to work on this, this part is going to require more work.
--
Best regards,
Aleksander Alekseev
Hi,
On 2023-02-09 13:06:04 +0300, Aleksander Alekseev wrote:
Yes, and the fact is that cmin == cmax is something that we don't normally
produceNot sure if this is particularly relevant to this discussion but I
can't resist noticing that the heap doesn't even store cmin and
cmax... There is only HeapTupleHeaderData.t_cid and flags. cmin/cmax
are merely smoke and mirrors we use to trick a user.
No, they're not just that. Yes, cmin/cmax aren't both stored on-disk, but if
both are needed, they *are* stored in-memory. We can do that because it's only
ever needed from within a transaction.
That's a spectactularly wrong argument in almost all cases. Unless you have a
way to get to full branch coverage or use a model checker that basically does
the same, testing isn't going to give you a whole lot of confidence that you
haven't introduced bugs.But neither will reviewing a lot of code...
And yet my review did figure out that your patch would have visibility
problems, which you did end up having, as you noticed yourself downthread :)
I've said my piece, as-is I vote to reject the patch.
Fair enough. I'm merely saying that rejecting a patch because it
doesn't include a TLA+ model is something novel :)
I obviously am not suggesting that (although some things could probably
benefit). Just that not having an example showing something working, isn't
sufficient to consider something suspicious OK.
And changes affecting heapam.c visibility semantics need extremely careful
review, I have the battle scars to prove that to be true :P.
Greetings,
Andres Freund
Hi,
And yet my review did figure out that your patch would have visibility
problems, which you did end up having, as you noticed yourself downthread :)
Yep, this particular implementation turned out to be buggy.
I don't buy your argument about DO UPDATE needing to be brought into
line with DO NOTHING. In any case I'm pretty sure that Tom's remarks
in 2016 about a behavioral inconsistencies (which you cited) actually
called for making DO NOTHING more like DO UPDATE -- not the other way
around.Interesting. Yep, we could use a bit of input from Tom on this one.
This of course would break backward compatibility. But we can always
invent something like:```
INSERT INTO ..
ON CONFLICT DO [NOTHING|UPDATE .. ]
[ALLOWING|FORBIDDING] SELF CONFLICTS;
```... if we really want to.
I suggest we discuss if we even want to support something like this
before processing further and then think about a particular
implementation if necessary.
One thing that occured to me during the discussion is that we don't
necessarily have to physically write one tuple at a time to the heap.
Alternatively we could use information about the existing unique
constraints and write only the needed tuples.
However, extension developers, as an example, often don't know the
underlying unique constraints (more specifically, it's difficult to
look for them and process them manually) and often have to process any
garbage the application developer passes to an extension.This of course is applicable not only to extensions, but to any
middleware between the DBMS and the application.
This however is arguably a niche use case. So maybe we don't want to
spend time on this.
--
Best regards,
Aleksander Alekseev
On Thu, 9 Feb 2023 at 05:43, Aleksander Alekseev
<aleksander@timescale.com> wrote:
I don't buy your argument about DO UPDATE needing to be brought into
line with DO NOTHING. In any case I'm pretty sure that Tom's remarks
in 2016 about a behavioral inconsistencies (which you cited) actually
called for making DO NOTHING more like DO UPDATE -- not the other way
around.Interesting. Yep, we could use a bit of input from Tom on this one.
I realize there are still unanswered conceptual questions about this
patch but with two votes against it seems unlikely to make much more
progress unless you rethink what you're trying to accomplish and
package it in a way that doesn't step on these more controversial
issues.
I'm going to mark the patch Returned With Feedback. If Tom or someone
else disagrees with Peter and Andres or has some new insights about
how to make it more palatable then we can always revisit that.
This of course would break backward compatibility. But we can always
invent something like:```
INSERT INTO ..
ON CONFLICT DO [NOTHING|UPDATE .. ]
[ALLOWING|FORBIDDING] SELF CONFLICTS;
```... if we really want to.
Something like that might be what I mean about new insights though I
suspect this is overly complex. It looks like having the ON CONFLICT
UPDATE happen before the row is already inserted might simplify things
conceptually but then it might make the implementation prohibitively
complex.
--
Gregory Stark
As Commitfest Manager