Remove INSERT privilege check at table creation of CTAS and matview

As per discussion with Peter Eisentraunt, the SQL standard specifies
that any tuple insertion done as part of CREATE TABLE AS happens without
any extra ACL check, so it makes little sense to keep a check for INSERT
privileges when using WITH DATA.  Materialized views are not part of the
standard, but similarly, this check can be confusing as this refers to
an access check on a table created within the same command as the one
that would insert data into this table.

This commit removes the INSERT privilege check for WITH DATA, the
default, that 846005e removed partially, but only for WITH NO DATA.

Author: Bharath Rupireddy
Discussion: https://postgr.es/m/d049c272-9a47-d783-46b0-46665b011598@enterprisedb.com
This commit is contained in:
Michael Paquier 2020-11-21 19:45:30 +09:00
parent a47834db0f
commit 878f3a19c6
7 changed files with 80 additions and 123 deletions

View File

@ -52,8 +52,7 @@ CREATE MATERIALIZED VIEW [ IF NOT EXISTS ] <replaceable>table_name</replaceable>
<para>
<command>CREATE MATERIALIZED VIEW</command> requires
<literal>CREATE</literal> privilege on the schema used for the materialized
view. If using <command>WITH DATA</command>, the default,
<literal>INSERT</literal> privilege is also required.
view.
</para>
</refsect1>

View File

@ -56,9 +56,7 @@ CREATE [ [ GLOBAL | LOCAL ] { TEMPORARY | TEMP } | UNLOGGED ] TABLE [ IF NOT EXI
<para>
<command>CREATE TABLE AS</command> requires <literal>CREATE</literal>
privilege on the schema used for the table. If using
<command>WITH DATA</command>, the default, <literal>INSERT</literal>
privilege is also required.
privilege on the schema used for the table.
</para>
</refsect1>

View File

@ -432,7 +432,6 @@ intorel_startup(DestReceiver *self, int operation, TupleDesc typeinfo)
DR_intorel *myState = (DR_intorel *) self;
IntoClause *into = myState->into;
bool is_matview;
char relkind;
List *attrList;
ObjectAddress intoRelationAddr;
Relation intoRelationDesc;
@ -443,7 +442,6 @@ intorel_startup(DestReceiver *self, int operation, TupleDesc typeinfo)
/* This code supports both CREATE TABLE AS and CREATE MATERIALIZED VIEW */
is_matview = (into->viewQuery != NULL);
relkind = is_matview ? RELKIND_MATVIEW : RELKIND_RELATION;
/*
* Build column definitions using "pre-cooked" type and collation info. If
@ -505,30 +503,6 @@ intorel_startup(DestReceiver *self, int operation, TupleDesc typeinfo)
*/
intoRelationDesc = table_open(intoRelationAddr.objectId, AccessExclusiveLock);
/*
* Check INSERT permission on the constructed table. Skip this check if
* WITH NO DATA is specified as only a table gets created with no tuples
* inserted, that is a case possible when using EXPLAIN ANALYZE or
* EXECUTE.
*/
if (!into->skipData)
{
RangeTblEntry *rte;
rte = makeNode(RangeTblEntry);
rte->rtekind = RTE_RELATION;
rte->relid = intoRelationAddr.objectId;
rte->relkind = relkind;
rte->rellockmode = RowExclusiveLock;
rte->requiredPerms = ACL_INSERT;
for (attnum = 1; attnum <= intoRelationDesc->rd_att->natts; attnum++)
rte->insertedCols = bms_add_member(rte->insertedCols,
attnum - FirstLowInvalidHeapAttributeNumber);
ExecCheckRTPerms(list_make1(rte), true);
}
/*
* Make sure the constructed table does not have RLS enabled.
*

View File

@ -596,15 +596,18 @@ ALTER DEFAULT PRIVILEGES FOR ROLE regress_matview_user
REVOKE INSERT ON TABLES FROM regress_matview_user;
GRANT ALL ON SCHEMA matview_schema TO public;
SET SESSION AUTHORIZATION regress_matview_user;
-- WITH DATA fails.
CREATE MATERIALIZED VIEW matview_schema.mv_withdata1 (a) AS
SELECT generate_series(1, 10) WITH DATA; -- error
ERROR: permission denied for materialized view mv_withdata1
SELECT generate_series(1, 10) WITH DATA;
EXPLAIN (ANALYZE, COSTS OFF, SUMMARY OFF, TIMING OFF)
CREATE MATERIALIZED VIEW matview_schema.mv_withdata1 (a) AS
SELECT generate_series(1, 10) WITH DATA; -- error
ERROR: permission denied for materialized view mv_withdata1
-- WITH NO DATA passes.
CREATE MATERIALIZED VIEW matview_schema.mv_withdata2 (a) AS
SELECT generate_series(1, 10) WITH DATA;
QUERY PLAN
--------------------------------------
ProjectSet (actual rows=10 loops=1)
-> Result (actual rows=1 loops=1)
(2 rows)
REFRESH MATERIALIZED VIEW matview_schema.mv_withdata2;
CREATE MATERIALIZED VIEW matview_schema.mv_nodata1 (a) AS
SELECT generate_series(1, 10) WITH NO DATA;
EXPLAIN (ANALYZE, COSTS OFF, SUMMARY OFF, TIMING OFF)
@ -616,11 +619,14 @@ EXPLAIN (ANALYZE, COSTS OFF, SUMMARY OFF, TIMING OFF)
-> Result (never executed)
(2 rows)
REFRESH MATERIALIZED VIEW matview_schema.mv_nodata2;
RESET SESSION AUTHORIZATION;
ALTER DEFAULT PRIVILEGES FOR ROLE regress_matview_user
GRANT INSERT ON TABLES TO regress_matview_user;
DROP SCHEMA matview_schema CASCADE;
NOTICE: drop cascades to 2 other objects
DETAIL: drop cascades to materialized view matview_schema.mv_nodata1
NOTICE: drop cascades to 4 other objects
DETAIL: drop cascades to materialized view matview_schema.mv_withdata1
drop cascades to materialized view matview_schema.mv_withdata2
drop cascades to materialized view matview_schema.mv_nodata1
drop cascades to materialized view matview_schema.mv_nodata2
DROP USER regress_matview_user;

View File

@ -20,79 +20,73 @@ ALTER DEFAULT PRIVILEGES FOR ROLE regress_selinto_user
REVOKE INSERT ON TABLES FROM regress_selinto_user;
GRANT ALL ON SCHEMA selinto_schema TO public;
SET SESSION AUTHORIZATION regress_selinto_user;
SELECT * INTO TABLE selinto_schema.tmp1
FROM pg_class WHERE relname like '%a%';
ERROR: permission denied for table tmp1
SELECT oid AS clsoid, relname, relnatts + 10 AS x
INTO selinto_schema.tmp2
FROM pg_class WHERE relname like '%b%';
ERROR: permission denied for table tmp2
-- WITH DATA, fails
CREATE TABLE selinto_schema.tbl_withdata (a,b,c)
AS SELECT oid,relname,relacl FROM pg_class
WHERE relname like '%c%' WITH DATA;
ERROR: permission denied for table tbl_withdata
-- WITH DATA, passes.
CREATE TABLE selinto_schema.tbl_withdata1 (a)
AS SELECT generate_series(1,3) WITH DATA;
INSERT INTO selinto_schema.tbl_withdata1 VALUES (4);
ERROR: permission denied for table tbl_withdata1
EXPLAIN (ANALYZE, COSTS OFF, SUMMARY OFF, TIMING OFF)
CREATE TABLE selinto_schema.tbl_withdata (a,b,c)
AS SELECT oid,relname,relacl FROM pg_class
WHERE relname like '%c%' WITH DATA;
ERROR: permission denied for table tbl_withdata
-- WITH NO DATA, passes.
CREATE TABLE selinto_schema.tbl_nodata1 (a) AS
SELECT oid FROM pg_class WHERE relname like '%c%' WITH NO DATA;
EXPLAIN (ANALYZE, COSTS OFF, SUMMARY OFF, TIMING OFF)
CREATE TABLE selinto_schema.tbl_nodata2 (a) AS
SELECT oid FROM pg_class WHERE relname like '%c%' WITH NO DATA;
QUERY PLAN
---------------------------------------
Seq Scan on pg_class (never executed)
Filter: (relname ~~ '%c%'::text)
CREATE TABLE selinto_schema.tbl_withdata2 (a) AS
SELECT generate_series(1,3) WITH DATA;
QUERY PLAN
--------------------------------------
ProjectSet (actual rows=3 loops=1)
-> Result (actual rows=1 loops=1)
(2 rows)
-- EXECUTE and WITH DATA, fails.
PREPARE data_sel AS
SELECT oid FROM pg_class WHERE relname like '%c%';
CREATE TABLE selinto_schema.tbl_withdata (a) AS
EXECUTE data_sel WITH DATA;
ERROR: permission denied for table tbl_withdata
-- WITH NO DATA, passes.
CREATE TABLE selinto_schema.tbl_nodata1 (a) AS
SELECT generate_series(1,3) WITH NO DATA;
EXPLAIN (ANALYZE, COSTS OFF, SUMMARY OFF, TIMING OFF)
CREATE TABLE selinto_schema.tbl_withdata (a) AS
CREATE TABLE selinto_schema.tbl_nodata2 (a) AS
SELECT generate_series(1,3) WITH NO DATA;
QUERY PLAN
-------------------------------
ProjectSet (never executed)
-> Result (never executed)
(2 rows)
-- EXECUTE and WITH DATA, passes.
PREPARE data_sel AS SELECT generate_series(1,3);
CREATE TABLE selinto_schema.tbl_withdata3 (a) AS
EXECUTE data_sel WITH DATA;
ERROR: permission denied for table tbl_withdata
EXPLAIN (ANALYZE, COSTS OFF, SUMMARY OFF, TIMING OFF)
CREATE TABLE selinto_schema.tbl_withdata4 (a) AS
EXECUTE data_sel WITH DATA;
QUERY PLAN
--------------------------------------
ProjectSet (actual rows=3 loops=1)
-> Result (actual rows=1 loops=1)
(2 rows)
-- EXECUTE and WITH NO DATA, passes.
CREATE TABLE selinto_schema.tbl_nodata3 (a) AS
EXECUTE data_sel WITH NO DATA;
EXPLAIN (ANALYZE, COSTS OFF, SUMMARY OFF, TIMING OFF)
CREATE TABLE selinto_schema.tbl_nodata4 (a) AS
EXECUTE data_sel WITH NO DATA;
QUERY PLAN
---------------------------------------
Seq Scan on pg_class (never executed)
Filter: (relname ~~ '%c%'::text)
QUERY PLAN
-------------------------------
ProjectSet (never executed)
-> Result (never executed)
(2 rows)
RESET SESSION AUTHORIZATION;
ALTER DEFAULT PRIVILEGES FOR ROLE regress_selinto_user
GRANT INSERT ON TABLES TO regress_selinto_user;
SET SESSION AUTHORIZATION regress_selinto_user;
SELECT * INTO TABLE selinto_schema.tmp1
FROM pg_class WHERE relname like '%a%'; -- OK
SELECT oid AS clsoid, relname, relnatts + 10 AS x
INTO selinto_schema.tmp2
FROM pg_class WHERE relname like '%b%'; -- OK
CREATE TABLE selinto_schema.tmp3 (a,b,c)
AS SELECT oid,relname,relacl FROM pg_class
WHERE relname like '%c%'; -- OK
RESET SESSION AUTHORIZATION;
DEALLOCATE data_sel;
DROP SCHEMA selinto_schema CASCADE;
NOTICE: drop cascades to 7 other objects
DETAIL: drop cascades to table selinto_schema.tbl_nodata1
NOTICE: drop cascades to 8 other objects
DETAIL: drop cascades to table selinto_schema.tbl_withdata1
drop cascades to table selinto_schema.tbl_withdata2
drop cascades to table selinto_schema.tbl_nodata1
drop cascades to table selinto_schema.tbl_nodata2
drop cascades to table selinto_schema.tbl_withdata3
drop cascades to table selinto_schema.tbl_withdata4
drop cascades to table selinto_schema.tbl_nodata3
drop cascades to table selinto_schema.tbl_nodata4
drop cascades to table selinto_schema.tmp1
drop cascades to table selinto_schema.tmp2
drop cascades to table selinto_schema.tmp3
DROP USER regress_selinto_user;
-- Tests for WITH NO DATA and column name consistency
CREATE TABLE ctas_base (i int, j int);

View File

@ -245,18 +245,18 @@ ALTER DEFAULT PRIVILEGES FOR ROLE regress_matview_user
GRANT ALL ON SCHEMA matview_schema TO public;
SET SESSION AUTHORIZATION regress_matview_user;
-- WITH DATA fails.
CREATE MATERIALIZED VIEW matview_schema.mv_withdata1 (a) AS
SELECT generate_series(1, 10) WITH DATA; -- error
SELECT generate_series(1, 10) WITH DATA;
EXPLAIN (ANALYZE, COSTS OFF, SUMMARY OFF, TIMING OFF)
CREATE MATERIALIZED VIEW matview_schema.mv_withdata1 (a) AS
SELECT generate_series(1, 10) WITH DATA; -- error
-- WITH NO DATA passes.
CREATE MATERIALIZED VIEW matview_schema.mv_withdata2 (a) AS
SELECT generate_series(1, 10) WITH DATA;
REFRESH MATERIALIZED VIEW matview_schema.mv_withdata2;
CREATE MATERIALIZED VIEW matview_schema.mv_nodata1 (a) AS
SELECT generate_series(1, 10) WITH NO DATA;
EXPLAIN (ANALYZE, COSTS OFF, SUMMARY OFF, TIMING OFF)
CREATE MATERIALIZED VIEW matview_schema.mv_nodata2 (a) AS
SELECT generate_series(1, 10) WITH NO DATA;
REFRESH MATERIALIZED VIEW matview_schema.mv_nodata2;
RESET SESSION AUTHORIZATION;
ALTER DEFAULT PRIVILEGES FOR ROLE regress_matview_user

View File

@ -26,32 +26,25 @@ ALTER DEFAULT PRIVILEGES FOR ROLE regress_selinto_user
GRANT ALL ON SCHEMA selinto_schema TO public;
SET SESSION AUTHORIZATION regress_selinto_user;
SELECT * INTO TABLE selinto_schema.tmp1
FROM pg_class WHERE relname like '%a%';
SELECT oid AS clsoid, relname, relnatts + 10 AS x
INTO selinto_schema.tmp2
FROM pg_class WHERE relname like '%b%';
-- WITH DATA, fails
CREATE TABLE selinto_schema.tbl_withdata (a,b,c)
AS SELECT oid,relname,relacl FROM pg_class
WHERE relname like '%c%' WITH DATA;
-- WITH DATA, passes.
CREATE TABLE selinto_schema.tbl_withdata1 (a)
AS SELECT generate_series(1,3) WITH DATA;
INSERT INTO selinto_schema.tbl_withdata1 VALUES (4);
EXPLAIN (ANALYZE, COSTS OFF, SUMMARY OFF, TIMING OFF)
CREATE TABLE selinto_schema.tbl_withdata (a,b,c)
AS SELECT oid,relname,relacl FROM pg_class
WHERE relname like '%c%' WITH DATA;
CREATE TABLE selinto_schema.tbl_withdata2 (a) AS
SELECT generate_series(1,3) WITH DATA;
-- WITH NO DATA, passes.
CREATE TABLE selinto_schema.tbl_nodata1 (a) AS
SELECT oid FROM pg_class WHERE relname like '%c%' WITH NO DATA;
SELECT generate_series(1,3) WITH NO DATA;
EXPLAIN (ANALYZE, COSTS OFF, SUMMARY OFF, TIMING OFF)
CREATE TABLE selinto_schema.tbl_nodata2 (a) AS
SELECT oid FROM pg_class WHERE relname like '%c%' WITH NO DATA;
-- EXECUTE and WITH DATA, fails.
PREPARE data_sel AS
SELECT oid FROM pg_class WHERE relname like '%c%';
CREATE TABLE selinto_schema.tbl_withdata (a) AS
SELECT generate_series(1,3) WITH NO DATA;
-- EXECUTE and WITH DATA, passes.
PREPARE data_sel AS SELECT generate_series(1,3);
CREATE TABLE selinto_schema.tbl_withdata3 (a) AS
EXECUTE data_sel WITH DATA;
EXPLAIN (ANALYZE, COSTS OFF, SUMMARY OFF, TIMING OFF)
CREATE TABLE selinto_schema.tbl_withdata (a) AS
CREATE TABLE selinto_schema.tbl_withdata4 (a) AS
EXECUTE data_sel WITH DATA;
-- EXECUTE and WITH NO DATA, passes.
CREATE TABLE selinto_schema.tbl_nodata3 (a) AS
@ -65,16 +58,9 @@ ALTER DEFAULT PRIVILEGES FOR ROLE regress_selinto_user
GRANT INSERT ON TABLES TO regress_selinto_user;
SET SESSION AUTHORIZATION regress_selinto_user;
SELECT * INTO TABLE selinto_schema.tmp1
FROM pg_class WHERE relname like '%a%'; -- OK
SELECT oid AS clsoid, relname, relnatts + 10 AS x
INTO selinto_schema.tmp2
FROM pg_class WHERE relname like '%b%'; -- OK
CREATE TABLE selinto_schema.tmp3 (a,b,c)
AS SELECT oid,relname,relacl FROM pg_class
WHERE relname like '%c%'; -- OK
RESET SESSION AUTHORIZATION;
DEALLOCATE data_sel;
DROP SCHEMA selinto_schema CASCADE;
DROP USER regress_selinto_user;