mirror of
https://github.com/postgres/postgres.git
synced 2025-04-21 12:05:57 +03:00
Fix ON CONFLICT bugs that manifest when used in rules.
Specifically the tlist and rti of the pseudo "excluded" relation weren't properly treated by expression_tree_walker, which lead to errors when excluded was referenced inside a rule because the varnos where not properly adjusted. Similar omissions in OffsetVarNodes and expression_tree_mutator had less impact, but should obviously be fixed nonetheless. A couple tests of for ON CONFLICT UPDATE into INSERT rule bearing relations have been added. In passing I updated a couple comments.
This commit is contained in:
parent
5c7df74204
commit
4af6e61a36
@ -1675,6 +1675,7 @@ ExecInitModifyTable(ModifyTable *node, EState *estate, int eflags)
|
|||||||
ExecSetSlotDescriptor(mtstate->mt_existing,
|
ExecSetSlotDescriptor(mtstate->mt_existing,
|
||||||
resultRelInfo->ri_RelationDesc->rd_att);
|
resultRelInfo->ri_RelationDesc->rd_att);
|
||||||
|
|
||||||
|
/* carried forward solely for the benefit of explain */
|
||||||
mtstate->mt_excludedtlist = node->exclRelTlist;
|
mtstate->mt_excludedtlist = node->exclRelTlist;
|
||||||
|
|
||||||
/* create target slot for UPDATE SET projection */
|
/* create target slot for UPDATE SET projection */
|
||||||
|
@ -1922,6 +1922,8 @@ expression_tree_walker(Node *node,
|
|||||||
return true;
|
return true;
|
||||||
if (walker(onconflict->onConflictWhere, context))
|
if (walker(onconflict->onConflictWhere, context))
|
||||||
return true;
|
return true;
|
||||||
|
if (walker(onconflict->exclRelTlist, context))
|
||||||
|
return true;
|
||||||
}
|
}
|
||||||
break;
|
break;
|
||||||
case T_JoinExpr:
|
case T_JoinExpr:
|
||||||
@ -2642,6 +2644,7 @@ expression_tree_mutator(Node *node,
|
|||||||
MUTATE(newnode->arbiterWhere, oc->arbiterWhere, Node *);
|
MUTATE(newnode->arbiterWhere, oc->arbiterWhere, Node *);
|
||||||
MUTATE(newnode->onConflictSet, oc->onConflictSet, List *);
|
MUTATE(newnode->onConflictSet, oc->onConflictSet, List *);
|
||||||
MUTATE(newnode->onConflictWhere, oc->onConflictWhere, Node *);
|
MUTATE(newnode->onConflictWhere, oc->onConflictWhere, Node *);
|
||||||
|
MUTATE(newnode->exclRelTlist, oc->exclRelTlist, List *);
|
||||||
|
|
||||||
return (Node *) newnode;
|
return (Node *) newnode;
|
||||||
}
|
}
|
||||||
|
@ -740,9 +740,9 @@ set_plan_refs(PlannerInfo *root, Plan *plan, int rtoffset)
|
|||||||
|
|
||||||
/*
|
/*
|
||||||
* We treat ModifyTable with ON CONFLICT as a form of 'pseudo
|
* We treat ModifyTable with ON CONFLICT as a form of 'pseudo
|
||||||
* join', where the inner side is the EXLUDED tuple. Therefore
|
* join', where the inner side is the EXCLUDED tuple.
|
||||||
* use fix_join_expr to setup the relevant variables to
|
* Therefore use fix_join_expr to setup the relevant variables
|
||||||
* INNER_VAR. We explicitly don't create any OUTER_VARs as
|
* to INNER_VAR. We explicitly don't create any OUTER_VARs as
|
||||||
* those are already used by RETURNING and it seems better to
|
* those are already used by RETURNING and it seems better to
|
||||||
* be non-conflicting.
|
* be non-conflicting.
|
||||||
*/
|
*/
|
||||||
@ -763,6 +763,9 @@ set_plan_refs(PlannerInfo *root, Plan *plan, int rtoffset)
|
|||||||
NULL, itlist,
|
NULL, itlist,
|
||||||
linitial_int(splan->resultRelations),
|
linitial_int(splan->resultRelations),
|
||||||
rtoffset);
|
rtoffset);
|
||||||
|
|
||||||
|
splan->exclRelTlist =
|
||||||
|
fix_scan_list(root, splan->exclRelTlist, rtoffset);
|
||||||
}
|
}
|
||||||
|
|
||||||
splan->nominalRelation += rtoffset;
|
splan->nominalRelation += rtoffset;
|
||||||
|
@ -426,9 +426,9 @@ OffsetVarNodes(Node *node, int offset, int sublevels_up)
|
|||||||
/*
|
/*
|
||||||
* If we are starting at a Query, and sublevels_up is zero, then we
|
* If we are starting at a Query, and sublevels_up is zero, then we
|
||||||
* must also fix rangetable indexes in the Query itself --- namely
|
* must also fix rangetable indexes in the Query itself --- namely
|
||||||
* resultRelation and rowMarks entries. sublevels_up cannot be zero
|
* resultRelation, exclRelIndex and rowMarks entries. sublevels_up
|
||||||
* when recursing into a subquery, so there's no need to have the same
|
* cannot be zero when recursing into a subquery, so there's no need
|
||||||
* logic inside OffsetVarNodes_walker.
|
* to have the same logic inside OffsetVarNodes_walker.
|
||||||
*/
|
*/
|
||||||
if (sublevels_up == 0)
|
if (sublevels_up == 0)
|
||||||
{
|
{
|
||||||
@ -436,6 +436,10 @@ OffsetVarNodes(Node *node, int offset, int sublevels_up)
|
|||||||
|
|
||||||
if (qry->resultRelation)
|
if (qry->resultRelation)
|
||||||
qry->resultRelation += offset;
|
qry->resultRelation += offset;
|
||||||
|
|
||||||
|
if (qry->onConflict && qry->onConflict->exclRelIndex)
|
||||||
|
qry->onConflict->exclRelIndex += offset;
|
||||||
|
|
||||||
foreach(l, qry->rowMarks)
|
foreach(l, qry->rowMarks)
|
||||||
{
|
{
|
||||||
RowMarkClause *rc = (RowMarkClause *) lfirst(l);
|
RowMarkClause *rc = (RowMarkClause *) lfirst(l);
|
||||||
@ -617,6 +621,11 @@ ChangeVarNodes(Node *node, int rt_index, int new_index, int sublevels_up)
|
|||||||
|
|
||||||
if (qry->resultRelation == rt_index)
|
if (qry->resultRelation == rt_index)
|
||||||
qry->resultRelation = new_index;
|
qry->resultRelation = new_index;
|
||||||
|
|
||||||
|
/* this is unlikely to ever be used, but ... */
|
||||||
|
if (qry->onConflict && qry->onConflict->exclRelIndex == rt_index)
|
||||||
|
qry->onConflict->exclRelIndex = new_index;
|
||||||
|
|
||||||
foreach(l, qry->rowMarks)
|
foreach(l, qry->rowMarks)
|
||||||
{
|
{
|
||||||
RowMarkClause *rc = (RowMarkClause *) lfirst(l);
|
RowMarkClause *rc = (RowMarkClause *) lfirst(l);
|
||||||
|
@ -2817,25 +2817,112 @@ CREATE RULE hat_upsert AS ON INSERT TO hats
|
|||||||
INSERT INTO hat_data VALUES (
|
INSERT INTO hat_data VALUES (
|
||||||
NEW.hat_name,
|
NEW.hat_name,
|
||||||
NEW.hat_color)
|
NEW.hat_color)
|
||||||
ON CONFLICT (hat_name) DO UPDATE SET hat_color = 'Orange' RETURNING *;
|
ON CONFLICT (hat_name)
|
||||||
|
DO UPDATE
|
||||||
|
SET hat_name = hat_data.hat_name, hat_color = excluded.hat_color
|
||||||
|
WHERE excluded.hat_color <> 'forbidden'
|
||||||
|
RETURNING *;
|
||||||
-- Works (does upsert)
|
-- Works (does upsert)
|
||||||
INSERT INTO hats VALUES ('h7', 'black') RETURNING *;
|
INSERT INTO hats VALUES ('h8', 'black') RETURNING *;
|
||||||
hat_name | hat_color
|
hat_name | hat_color
|
||||||
------------+------------
|
------------+------------
|
||||||
h7 | Orange
|
h8 | black
|
||||||
|
(1 row)
|
||||||
|
|
||||||
|
SELECT * FROM hat_data WHERE hat_name = 'h8';
|
||||||
|
hat_name | hat_color
|
||||||
|
------------+------------
|
||||||
|
h8 | black
|
||||||
|
(1 row)
|
||||||
|
|
||||||
|
INSERT INTO hats VALUES ('h8', 'white') RETURNING *;
|
||||||
|
hat_name | hat_color
|
||||||
|
------------+------------
|
||||||
|
h8 | white
|
||||||
|
(1 row)
|
||||||
|
|
||||||
|
SELECT * FROM hat_data WHERE hat_name = 'h8';
|
||||||
|
hat_name | hat_color
|
||||||
|
------------+------------
|
||||||
|
h8 | white
|
||||||
|
(1 row)
|
||||||
|
|
||||||
|
INSERT INTO hats VALUES ('h8', 'forbidden') RETURNING *;
|
||||||
|
hat_name | hat_color
|
||||||
|
----------+-----------
|
||||||
|
(0 rows)
|
||||||
|
|
||||||
|
SELECT * FROM hat_data WHERE hat_name = 'h8';
|
||||||
|
hat_name | hat_color
|
||||||
|
------------+------------
|
||||||
|
h8 | white
|
||||||
(1 row)
|
(1 row)
|
||||||
|
|
||||||
SELECT tablename, rulename, definition FROM pg_rules
|
SELECT tablename, rulename, definition FROM pg_rules
|
||||||
WHERE tablename = 'hats';
|
WHERE tablename = 'hats';
|
||||||
tablename | rulename | definition
|
tablename | rulename | definition
|
||||||
-----------+------------+-----------------------------------------------------------------------------------------------
|
-----------+------------+-------------------------------------------------------------------------------------------------------------------------------
|
||||||
hats | hat_upsert | CREATE RULE hat_upsert AS +
|
hats | hat_upsert | CREATE RULE hat_upsert AS +
|
||||||
| | ON INSERT TO hats DO INSTEAD INSERT INTO hat_data (hat_name, hat_color) +
|
| | ON INSERT TO hats DO INSTEAD INSERT INTO hat_data (hat_name, hat_color) +
|
||||||
| | VALUES (new.hat_name, new.hat_color) ON CONFLICT DO UPDATE SET hat_color = 'Orange'::bpchar+
|
| | VALUES (new.hat_name, new.hat_color) ON CONFLICT DO UPDATE SET hat_name = hat_data.hat_name, hat_color = excluded.hat_color+
|
||||||
| | RETURNING hat_data.hat_name, +
|
| | WHERE (excluded.hat_color <> 'forbidden'::bpchar) +
|
||||||
|
| | RETURNING hat_data.hat_name, +
|
||||||
| | hat_data.hat_color;
|
| | hat_data.hat_color;
|
||||||
(1 row)
|
(1 row)
|
||||||
|
|
||||||
|
-- ensure explain works for on insert conflict rules
|
||||||
|
explain (costs off) INSERT INTO hats VALUES ('h8', 'forbidden') RETURNING *;
|
||||||
|
QUERY PLAN
|
||||||
|
----------------------------------------------------------------
|
||||||
|
Insert on hat_data
|
||||||
|
Conflict Resolution: UPDATE
|
||||||
|
Conflict Arbiter Indexes: hat_data_pkey
|
||||||
|
Conflict Filter: (excluded.hat_color <> 'forbidden'::bpchar)
|
||||||
|
-> Result
|
||||||
|
(5 rows)
|
||||||
|
|
||||||
|
-- ensure upserting into a rule, with a CTE (different offsets!) works
|
||||||
|
WITH data(hat_name, hat_color) AS (
|
||||||
|
VALUES ('h8', 'green'),
|
||||||
|
('h9', 'blue'),
|
||||||
|
('h7', 'forbidden')
|
||||||
|
)
|
||||||
|
INSERT INTO hats
|
||||||
|
SELECT * FROM data
|
||||||
|
RETURNING *;
|
||||||
|
hat_name | hat_color
|
||||||
|
------------+------------
|
||||||
|
h8 | green
|
||||||
|
h9 | blue
|
||||||
|
(2 rows)
|
||||||
|
|
||||||
|
EXPLAIN (costs off) WITH data(hat_name, hat_color) AS (
|
||||||
|
VALUES ('h8', 'green'),
|
||||||
|
('h9', 'blue'),
|
||||||
|
('h7', 'forbidden')
|
||||||
|
)
|
||||||
|
INSERT INTO hats
|
||||||
|
SELECT * FROM data
|
||||||
|
RETURNING *;
|
||||||
|
QUERY PLAN
|
||||||
|
----------------------------------------------------------------
|
||||||
|
Insert on hat_data
|
||||||
|
Conflict Resolution: UPDATE
|
||||||
|
Conflict Arbiter Indexes: hat_data_pkey
|
||||||
|
Conflict Filter: (excluded.hat_color <> 'forbidden'::bpchar)
|
||||||
|
CTE data
|
||||||
|
-> Values Scan on "*VALUES*"
|
||||||
|
-> CTE Scan on data
|
||||||
|
(7 rows)
|
||||||
|
|
||||||
|
SELECT * FROM hat_data WHERE hat_name IN ('h8', 'h9', 'h7') ORDER BY hat_name;
|
||||||
|
hat_name | hat_color
|
||||||
|
------------+------------
|
||||||
|
h7 | black
|
||||||
|
h8 | green
|
||||||
|
h9 | blue
|
||||||
|
(3 rows)
|
||||||
|
|
||||||
DROP RULE hat_upsert ON hats;
|
DROP RULE hat_upsert ON hats;
|
||||||
drop table hats;
|
drop table hats;
|
||||||
drop table hat_data;
|
drop table hat_data;
|
||||||
|
@ -1074,12 +1074,43 @@ CREATE RULE hat_upsert AS ON INSERT TO hats
|
|||||||
INSERT INTO hat_data VALUES (
|
INSERT INTO hat_data VALUES (
|
||||||
NEW.hat_name,
|
NEW.hat_name,
|
||||||
NEW.hat_color)
|
NEW.hat_color)
|
||||||
ON CONFLICT (hat_name) DO UPDATE SET hat_color = 'Orange' RETURNING *;
|
ON CONFLICT (hat_name)
|
||||||
|
DO UPDATE
|
||||||
|
SET hat_name = hat_data.hat_name, hat_color = excluded.hat_color
|
||||||
|
WHERE excluded.hat_color <> 'forbidden'
|
||||||
|
RETURNING *;
|
||||||
|
|
||||||
-- Works (does upsert)
|
-- Works (does upsert)
|
||||||
INSERT INTO hats VALUES ('h7', 'black') RETURNING *;
|
INSERT INTO hats VALUES ('h8', 'black') RETURNING *;
|
||||||
|
SELECT * FROM hat_data WHERE hat_name = 'h8';
|
||||||
|
INSERT INTO hats VALUES ('h8', 'white') RETURNING *;
|
||||||
|
SELECT * FROM hat_data WHERE hat_name = 'h8';
|
||||||
|
INSERT INTO hats VALUES ('h8', 'forbidden') RETURNING *;
|
||||||
|
SELECT * FROM hat_data WHERE hat_name = 'h8';
|
||||||
SELECT tablename, rulename, definition FROM pg_rules
|
SELECT tablename, rulename, definition FROM pg_rules
|
||||||
WHERE tablename = 'hats';
|
WHERE tablename = 'hats';
|
||||||
|
-- ensure explain works for on insert conflict rules
|
||||||
|
explain (costs off) INSERT INTO hats VALUES ('h8', 'forbidden') RETURNING *;
|
||||||
|
|
||||||
|
-- ensure upserting into a rule, with a CTE (different offsets!) works
|
||||||
|
WITH data(hat_name, hat_color) AS (
|
||||||
|
VALUES ('h8', 'green'),
|
||||||
|
('h9', 'blue'),
|
||||||
|
('h7', 'forbidden')
|
||||||
|
)
|
||||||
|
INSERT INTO hats
|
||||||
|
SELECT * FROM data
|
||||||
|
RETURNING *;
|
||||||
|
EXPLAIN (costs off) WITH data(hat_name, hat_color) AS (
|
||||||
|
VALUES ('h8', 'green'),
|
||||||
|
('h9', 'blue'),
|
||||||
|
('h7', 'forbidden')
|
||||||
|
)
|
||||||
|
INSERT INTO hats
|
||||||
|
SELECT * FROM data
|
||||||
|
RETURNING *;
|
||||||
|
SELECT * FROM hat_data WHERE hat_name IN ('h8', 'h9', 'h7') ORDER BY hat_name;
|
||||||
|
|
||||||
DROP RULE hat_upsert ON hats;
|
DROP RULE hat_upsert ON hats;
|
||||||
|
|
||||||
drop table hats;
|
drop table hats;
|
||||||
|
Loading…
x
Reference in New Issue
Block a user