1
0
mirror of https://github.com/postgres/postgres.git synced 2025-07-15 19:21:59 +03:00

Fix INSERT ON CONFLICT UPDATE through a view that isn't just SELECT *.

When expanding an updatable view that is an INSERT's target, the rewriter
failed to rewrite Vars in the ON CONFLICT UPDATE clause.  This accidentally
worked if the view was just "SELECT * FROM ...", as the transformation
would be a no-op in that case.  With more complicated view targetlists,
this omission would often lead to "attribute ... has the wrong type" errors
or even crashes, as reported by Mario De Frutos Dieguez.

Fix by adding code to rewriteTargetView to fix up the data structure
correctly.  The easiest way to update the exclRelTlist list is to rebuild
it from scratch looking at the new target relation, so factor the code
for that out of transformOnConflictClause to make it sharable.

In passing, avoid duplicate permissions checks against the EXCLUDED
pseudo-relation, and prevent useless view expansion of that relation's
dummy RTE.  The latter is only known to happen (after this patch) in cases
where the query would fail later due to not having any INSTEAD OF triggers
for the view.  But by exactly that token, it would create an unintended
and very poorly tested state of the query data structure, so it seems like
a good idea to prevent it from happening at all.

This has been broken since ON CONFLICT was introduced, so back-patch
to 9.5.

Dean Rasheed, based on an earlier patch by Amit Langote;
comment-kibitzing and back-patching by me

Discussion: https://postgr.es/m/CAFYwGJ0xfzy8jaK80hVN2eUWr6huce0RU8AgU04MGD00igqkTg@mail.gmail.com
This commit is contained in:
Tom Lane
2018-08-04 19:38:58 -04:00
parent 5a23c74b63
commit b8a1247a34
5 changed files with 514 additions and 57 deletions

View File

@ -2578,3 +2578,197 @@ ERROR: new row violates check option for view "wcowrtest_v2"
DETAIL: Failing row contains (2, no such row in sometable).
drop view wcowrtest_v, wcowrtest_v2;
drop table wcowrtest, sometable;
-- Check INSERT .. ON CONFLICT DO UPDATE works correctly when the view's
-- columns are named and ordered differently than the underlying table's.
create table uv_iocu_tab (a text unique, b float);
insert into uv_iocu_tab values ('xyxyxy', 0);
create view uv_iocu_view as
select b, b+1 as c, a, '2.0'::text as two from uv_iocu_tab;
insert into uv_iocu_view (a, b) values ('xyxyxy', 1)
on conflict (a) do update set b = uv_iocu_view.b;
select * from uv_iocu_tab;
a | b
--------+---
xyxyxy | 0
(1 row)
insert into uv_iocu_view (a, b) values ('xyxyxy', 1)
on conflict (a) do update set b = excluded.b;
select * from uv_iocu_tab;
a | b
--------+---
xyxyxy | 1
(1 row)
-- OK to access view columns that are not present in underlying base
-- relation in the ON CONFLICT portion of the query
insert into uv_iocu_view (a, b) values ('xyxyxy', 3)
on conflict (a) do update set b = cast(excluded.two as float);
select * from uv_iocu_tab;
a | b
--------+---
xyxyxy | 2
(1 row)
explain (costs off)
insert into uv_iocu_view (a, b) values ('xyxyxy', 3)
on conflict (a) do update set b = excluded.b where excluded.c > 0;
QUERY PLAN
-----------------------------------------------------------------------------------
Insert on uv_iocu_tab
Conflict Resolution: UPDATE
Conflict Arbiter Indexes: uv_iocu_tab_a_key
Conflict Filter: ((excluded.b + '1'::double precision) > '0'::double precision)
-> Result
(5 rows)
insert into uv_iocu_view (a, b) values ('xyxyxy', 3)
on conflict (a) do update set b = excluded.b where excluded.c > 0;
select * from uv_iocu_tab;
a | b
--------+---
xyxyxy | 3
(1 row)
drop view uv_iocu_view;
drop table uv_iocu_tab;
-- Test whole-row references to the view
create table uv_iocu_tab (a int unique, b text);
create view uv_iocu_view as
select b as bb, a as aa, uv_iocu_tab::text as cc from uv_iocu_tab;
insert into uv_iocu_view (aa,bb) values (1,'x');
explain (costs off)
insert into uv_iocu_view (aa,bb) values (1,'y')
on conflict (aa) do update set bb = 'Rejected: '||excluded.*
where excluded.aa > 0
and excluded.bb != ''
and excluded.cc is not null;
QUERY PLAN
---------------------------------------------------------------------------------------------------------
Insert on uv_iocu_tab
Conflict Resolution: UPDATE
Conflict Arbiter Indexes: uv_iocu_tab_a_key
Conflict Filter: ((excluded.a > 0) AND (excluded.b <> ''::text) AND ((excluded.*)::text IS NOT NULL))
-> Result
(5 rows)
insert into uv_iocu_view (aa,bb) values (1,'y')
on conflict (aa) do update set bb = 'Rejected: '||excluded.*
where excluded.aa > 0
and excluded.bb != ''
and excluded.cc is not null;
select * from uv_iocu_view;
bb | aa | cc
-------------------------+----+---------------------------------
Rejected: (y,1,"(1,y)") | 1 | (1,"Rejected: (y,1,""(1,y)"")")
(1 row)
-- Test omitting a column of the base relation
delete from uv_iocu_view;
insert into uv_iocu_view (aa,bb) values (1,'x');
insert into uv_iocu_view (aa) values (1)
on conflict (aa) do update set bb = 'Rejected: '||excluded.*;
select * from uv_iocu_view;
bb | aa | cc
-----------------------+----+-------------------------------
Rejected: (,1,"(1,)") | 1 | (1,"Rejected: (,1,""(1,)"")")
(1 row)
alter table uv_iocu_tab alter column b set default 'table default';
insert into uv_iocu_view (aa) values (1)
on conflict (aa) do update set bb = 'Rejected: '||excluded.*;
select * from uv_iocu_view;
bb | aa | cc
-------------------------------------------------------+----+---------------------------------------------------------------------
Rejected: ("table default",1,"(1,""table default"")") | 1 | (1,"Rejected: (""table default"",1,""(1,""""table default"""")"")")
(1 row)
alter view uv_iocu_view alter column bb set default 'view default';
insert into uv_iocu_view (aa) values (1)
on conflict (aa) do update set bb = 'Rejected: '||excluded.*;
select * from uv_iocu_view;
bb | aa | cc
-----------------------------------------------------+----+-------------------------------------------------------------------
Rejected: ("view default",1,"(1,""view default"")") | 1 | (1,"Rejected: (""view default"",1,""(1,""""view default"""")"")")
(1 row)
-- Should fail to update non-updatable columns
insert into uv_iocu_view (aa) values (1)
on conflict (aa) do update set cc = 'XXX';
ERROR: cannot insert into column "cc" of view "uv_iocu_view"
DETAIL: View columns that are not columns of their base relation are not updatable.
drop view uv_iocu_view;
drop table uv_iocu_tab;
-- ON CONFLICT DO UPDATE permissions checks
create user regress_view_user1;
create user regress_view_user2;
set session authorization regress_view_user1;
create table base_tbl(a int unique, b text, c float);
insert into base_tbl values (1,'xxx',1.0);
create view rw_view1 as select b as bb, c as cc, a as aa from base_tbl;
grant select (aa,bb) on rw_view1 to regress_view_user2;
grant insert on rw_view1 to regress_view_user2;
grant update (bb) on rw_view1 to regress_view_user2;
set session authorization regress_view_user2;
insert into rw_view1 values ('yyy',2.0,1)
on conflict (aa) do update set bb = excluded.cc; -- Not allowed
ERROR: permission denied for view rw_view1
insert into rw_view1 values ('yyy',2.0,1)
on conflict (aa) do update set bb = rw_view1.cc; -- Not allowed
ERROR: permission denied for view rw_view1
insert into rw_view1 values ('yyy',2.0,1)
on conflict (aa) do update set bb = excluded.bb; -- OK
insert into rw_view1 values ('zzz',2.0,1)
on conflict (aa) do update set bb = rw_view1.bb||'xxx'; -- OK
insert into rw_view1 values ('zzz',2.0,1)
on conflict (aa) do update set cc = 3.0; -- Not allowed
ERROR: permission denied for view rw_view1
reset session authorization;
select * from base_tbl;
a | b | c
---+--------+---
1 | yyyxxx | 1
(1 row)
set session authorization regress_view_user1;
grant select (a,b) on base_tbl to regress_view_user2;
grant insert (a,b) on base_tbl to regress_view_user2;
grant update (a,b) on base_tbl to regress_view_user2;
set session authorization regress_view_user2;
create view rw_view2 as select b as bb, c as cc, a as aa from base_tbl;
insert into rw_view2 (aa,bb) values (1,'xxx')
on conflict (aa) do update set bb = excluded.bb; -- Not allowed
ERROR: permission denied for table base_tbl
create view rw_view3 as select b as bb, a as aa from base_tbl;
insert into rw_view3 (aa,bb) values (1,'xxx')
on conflict (aa) do update set bb = excluded.bb; -- OK
reset session authorization;
select * from base_tbl;
a | b | c
---+-----+---
1 | xxx | 1
(1 row)
set session authorization regress_view_user2;
create view rw_view4 as select aa, bb, cc FROM rw_view1;
insert into rw_view4 (aa,bb) values (1,'yyy')
on conflict (aa) do update set bb = excluded.bb; -- Not allowed
ERROR: permission denied for view rw_view1
create view rw_view5 as select aa, bb FROM rw_view1;
insert into rw_view5 (aa,bb) values (1,'yyy')
on conflict (aa) do update set bb = excluded.bb; -- OK
reset session authorization;
select * from base_tbl;
a | b | c
---+-----+---
1 | yyy | 1
(1 row)
drop view rw_view5;
drop view rw_view4;
drop view rw_view3;
drop view rw_view2;
drop view rw_view1;
drop table base_tbl;
drop user regress_view_user1;
drop user regress_view_user2;

View File

@ -1244,3 +1244,138 @@ insert into wcowrtest_v2 values (2, 'no such row in sometable');
drop view wcowrtest_v, wcowrtest_v2;
drop table wcowrtest, sometable;
-- Check INSERT .. ON CONFLICT DO UPDATE works correctly when the view's
-- columns are named and ordered differently than the underlying table's.
create table uv_iocu_tab (a text unique, b float);
insert into uv_iocu_tab values ('xyxyxy', 0);
create view uv_iocu_view as
select b, b+1 as c, a, '2.0'::text as two from uv_iocu_tab;
insert into uv_iocu_view (a, b) values ('xyxyxy', 1)
on conflict (a) do update set b = uv_iocu_view.b;
select * from uv_iocu_tab;
insert into uv_iocu_view (a, b) values ('xyxyxy', 1)
on conflict (a) do update set b = excluded.b;
select * from uv_iocu_tab;
-- OK to access view columns that are not present in underlying base
-- relation in the ON CONFLICT portion of the query
insert into uv_iocu_view (a, b) values ('xyxyxy', 3)
on conflict (a) do update set b = cast(excluded.two as float);
select * from uv_iocu_tab;
explain (costs off)
insert into uv_iocu_view (a, b) values ('xyxyxy', 3)
on conflict (a) do update set b = excluded.b where excluded.c > 0;
insert into uv_iocu_view (a, b) values ('xyxyxy', 3)
on conflict (a) do update set b = excluded.b where excluded.c > 0;
select * from uv_iocu_tab;
drop view uv_iocu_view;
drop table uv_iocu_tab;
-- Test whole-row references to the view
create table uv_iocu_tab (a int unique, b text);
create view uv_iocu_view as
select b as bb, a as aa, uv_iocu_tab::text as cc from uv_iocu_tab;
insert into uv_iocu_view (aa,bb) values (1,'x');
explain (costs off)
insert into uv_iocu_view (aa,bb) values (1,'y')
on conflict (aa) do update set bb = 'Rejected: '||excluded.*
where excluded.aa > 0
and excluded.bb != ''
and excluded.cc is not null;
insert into uv_iocu_view (aa,bb) values (1,'y')
on conflict (aa) do update set bb = 'Rejected: '||excluded.*
where excluded.aa > 0
and excluded.bb != ''
and excluded.cc is not null;
select * from uv_iocu_view;
-- Test omitting a column of the base relation
delete from uv_iocu_view;
insert into uv_iocu_view (aa,bb) values (1,'x');
insert into uv_iocu_view (aa) values (1)
on conflict (aa) do update set bb = 'Rejected: '||excluded.*;
select * from uv_iocu_view;
alter table uv_iocu_tab alter column b set default 'table default';
insert into uv_iocu_view (aa) values (1)
on conflict (aa) do update set bb = 'Rejected: '||excluded.*;
select * from uv_iocu_view;
alter view uv_iocu_view alter column bb set default 'view default';
insert into uv_iocu_view (aa) values (1)
on conflict (aa) do update set bb = 'Rejected: '||excluded.*;
select * from uv_iocu_view;
-- Should fail to update non-updatable columns
insert into uv_iocu_view (aa) values (1)
on conflict (aa) do update set cc = 'XXX';
drop view uv_iocu_view;
drop table uv_iocu_tab;
-- ON CONFLICT DO UPDATE permissions checks
create user regress_view_user1;
create user regress_view_user2;
set session authorization regress_view_user1;
create table base_tbl(a int unique, b text, c float);
insert into base_tbl values (1,'xxx',1.0);
create view rw_view1 as select b as bb, c as cc, a as aa from base_tbl;
grant select (aa,bb) on rw_view1 to regress_view_user2;
grant insert on rw_view1 to regress_view_user2;
grant update (bb) on rw_view1 to regress_view_user2;
set session authorization regress_view_user2;
insert into rw_view1 values ('yyy',2.0,1)
on conflict (aa) do update set bb = excluded.cc; -- Not allowed
insert into rw_view1 values ('yyy',2.0,1)
on conflict (aa) do update set bb = rw_view1.cc; -- Not allowed
insert into rw_view1 values ('yyy',2.0,1)
on conflict (aa) do update set bb = excluded.bb; -- OK
insert into rw_view1 values ('zzz',2.0,1)
on conflict (aa) do update set bb = rw_view1.bb||'xxx'; -- OK
insert into rw_view1 values ('zzz',2.0,1)
on conflict (aa) do update set cc = 3.0; -- Not allowed
reset session authorization;
select * from base_tbl;
set session authorization regress_view_user1;
grant select (a,b) on base_tbl to regress_view_user2;
grant insert (a,b) on base_tbl to regress_view_user2;
grant update (a,b) on base_tbl to regress_view_user2;
set session authorization regress_view_user2;
create view rw_view2 as select b as bb, c as cc, a as aa from base_tbl;
insert into rw_view2 (aa,bb) values (1,'xxx')
on conflict (aa) do update set bb = excluded.bb; -- Not allowed
create view rw_view3 as select b as bb, a as aa from base_tbl;
insert into rw_view3 (aa,bb) values (1,'xxx')
on conflict (aa) do update set bb = excluded.bb; -- OK
reset session authorization;
select * from base_tbl;
set session authorization regress_view_user2;
create view rw_view4 as select aa, bb, cc FROM rw_view1;
insert into rw_view4 (aa,bb) values (1,'yyy')
on conflict (aa) do update set bb = excluded.bb; -- Not allowed
create view rw_view5 as select aa, bb FROM rw_view1;
insert into rw_view5 (aa,bb) values (1,'yyy')
on conflict (aa) do update set bb = excluded.bb; -- OK
reset session authorization;
select * from base_tbl;
drop view rw_view5;
drop view rw_view4;
drop view rw_view3;
drop view rw_view2;
drop view rw_view1;
drop table base_tbl;
drop user regress_view_user1;
drop user regress_view_user2;