diff --git a/doc/src/sgml/ref/create_materialized_view.sgml b/doc/src/sgml/ref/create_materialized_view.sgml index 5ba851b687..e4ea049eff 100644 --- a/doc/src/sgml/ref/create_materialized_view.sgml +++ b/doc/src/sgml/ref/create_materialized_view.sgml @@ -48,6 +48,13 @@ CREATE MATERIALIZED VIEW [ IF NOT EXISTS ] table_name A materialized view has many of the same properties as a table, but there is no support for temporary materialized views. + + + CREATE MATERIALIZED VIEW requires + CREATE privilege on the schema used for the materialized + view. If using WITH DATA, the default, + INSERT privilege is also required. + diff --git a/doc/src/sgml/ref/create_table_as.sgml b/doc/src/sgml/ref/create_table_as.sgml index bcbd73b227..2cac4e3ec0 100644 --- a/doc/src/sgml/ref/create_table_as.sgml +++ b/doc/src/sgml/ref/create_table_as.sgml @@ -53,6 +53,13 @@ CREATE [ [ GLOBAL | LOCAL ] { TEMPORARY | TEMP } | UNLOGGED ] TABLE [ IF NOT EXI defining SELECT statement whenever it is queried. + + + CREATE TABLE AS requires CREATE + privilege on the schema used for the table. If using + WITH DATA, the default, INSERT + privilege is also required. + diff --git a/src/backend/commands/createas.c b/src/backend/commands/createas.c index d53ec952d0..37649eafa8 100644 --- a/src/backend/commands/createas.c +++ b/src/backend/commands/createas.c @@ -436,7 +436,6 @@ intorel_startup(DestReceiver *self, int operation, TupleDesc typeinfo) List *attrList; ObjectAddress intoRelationAddr; Relation intoRelationDesc; - RangeTblEntry *rte; ListCell *lc; int attnum; @@ -507,23 +506,28 @@ intorel_startup(DestReceiver *self, int operation, TupleDesc typeinfo) intoRelationDesc = table_open(intoRelationAddr.objectId, AccessExclusiveLock); /* - * Check INSERT permission on the constructed table. - * - * XXX: It would arguably make sense to skip this check if into->skipData - * is true. + * 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. */ - rte = makeNode(RangeTblEntry); - rte->rtekind = RTE_RELATION; - rte->relid = intoRelationAddr.objectId; - rte->relkind = relkind; - rte->rellockmode = RowExclusiveLock; - rte->requiredPerms = ACL_INSERT; + if (!into->skipData) + { + RangeTblEntry *rte; - for (attnum = 1; attnum <= intoRelationDesc->rd_att->natts; attnum++) - rte->insertedCols = bms_add_member(rte->insertedCols, - attnum - FirstLowInvalidHeapAttributeNumber); + rte = makeNode(RangeTblEntry); + rte->rtekind = RTE_RELATION; + rte->relid = intoRelationAddr.objectId; + rte->relkind = relkind; + rte->rellockmode = RowExclusiveLock; + rte->requiredPerms = ACL_INSERT; - ExecCheckRTPerms(list_make1(rte), true); + 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. @@ -552,7 +556,15 @@ intorel_startup(DestReceiver *self, int operation, TupleDesc typeinfo) myState->reladdr = intoRelationAddr; myState->output_cid = GetCurrentCommandId(true); myState->ti_options = TABLE_INSERT_SKIP_FSM; - myState->bistate = GetBulkInsertState(); + + /* + * If WITH NO DATA is specified, there is no need to set up the state for + * bulk inserts as there are no tuples to insert. + */ + if (!into->skipData) + myState->bistate = GetBulkInsertState(); + else + myState->bistate = NULL; /* * Valid smgr_targblock implies something already wrote to the relation. @@ -569,20 +581,23 @@ intorel_receive(TupleTableSlot *slot, DestReceiver *self) { DR_intorel *myState = (DR_intorel *) self; - /* - * Note that the input slot might not be of the type of the target - * relation. That's supported by table_tuple_insert(), but slightly less - * efficient than inserting with the right slot - but the alternative - * would be to copy into a slot of the right type, which would not be - * cheap either. This also doesn't allow accessing per-AM data (say a - * tuple's xmin), but since we don't do that here... - */ - - table_tuple_insert(myState->rel, - slot, - myState->output_cid, - myState->ti_options, - myState->bistate); + /* Nothing to insert if WITH NO DATA is specified. */ + if (!myState->into->skipData) + { + /* + * Note that the input slot might not be of the type of the target + * relation. That's supported by table_tuple_insert(), but slightly + * less efficient than inserting with the right slot - but the + * alternative would be to copy into a slot of the right type, which + * would not be cheap either. This also doesn't allow accessing per-AM + * data (say a tuple's xmin), but since we don't do that here... + */ + table_tuple_insert(myState->rel, + slot, + myState->output_cid, + myState->ti_options, + myState->bistate); + } /* We know this is a newly created relation, so there are no indexes */ @@ -596,10 +611,13 @@ static void intorel_shutdown(DestReceiver *self) { DR_intorel *myState = (DR_intorel *) self; + IntoClause *into = myState->into; - FreeBulkInsertState(myState->bistate); - - table_finish_bulk_insert(myState->rel, myState->ti_options); + if (!into->skipData) + { + FreeBulkInsertState(myState->bistate); + table_finish_bulk_insert(myState->rel, myState->ti_options); + } /* close rel, but keep lock until commit */ table_close(myState->rel, NoLock); diff --git a/src/test/regress/expected/matview.out b/src/test/regress/expected/matview.out index d0121a7b0b..328c3118b6 100644 --- a/src/test/regress/expected/matview.out +++ b/src/test/regress/expected/matview.out @@ -589,3 +589,38 @@ SELECT * FROM mvtest2; ERROR: materialized view "mvtest2" has not been populated HINT: Use the REFRESH MATERIALIZED VIEW command. ROLLBACK; +-- INSERT privileges if relation owner is not allowed to insert. +CREATE SCHEMA matview_schema; +CREATE USER regress_matview_user; +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 +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_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; + QUERY PLAN +------------------------------- + ProjectSet (never executed) + -> Result (never executed) +(2 rows) + +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 +drop cascades to materialized view matview_schema.mv_nodata2 +DROP USER regress_matview_user; diff --git a/src/test/regress/expected/select_into.out b/src/test/regress/expected/select_into.out index f373fae679..45068afca7 100644 --- a/src/test/regress/expected/select_into.out +++ b/src/test/regress/expected/select_into.out @@ -21,16 +21,56 @@ 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%'; -- Error + 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 + INTO selinto_schema.tmp2 + FROM pg_class WHERE relname like '%b%'; ERROR: permission denied for table tmp2 -CREATE TABLE selinto_schema.tmp3 (a,b,c) - AS SELECT oid,relname,relacl FROM pg_class - WHERE relname like '%c%'; -- Error -ERROR: permission denied for table tmp3 +-- 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 +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) +(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 +EXPLAIN (ANALYZE, COSTS OFF, SUMMARY OFF, TIMING OFF) + CREATE TABLE selinto_schema.tbl_withdata (a) AS + EXECUTE data_sel WITH DATA; +ERROR: permission denied for table tbl_withdata +-- 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) +(2 rows) + RESET SESSION AUTHORIZATION; ALTER DEFAULT PRIVILEGES FOR ROLE regress_selinto_user GRANT INSERT ON TABLES TO regress_selinto_user; @@ -45,8 +85,12 @@ CREATE TABLE selinto_schema.tmp3 (a,b,c) WHERE relname like '%c%'; -- OK RESET SESSION AUTHORIZATION; DROP SCHEMA selinto_schema CASCADE; -NOTICE: drop cascades to 3 other objects -DETAIL: drop cascades to table selinto_schema.tmp1 +NOTICE: drop cascades to 7 other objects +DETAIL: drop cascades to table selinto_schema.tbl_nodata1 +drop cascades to table selinto_schema.tbl_nodata2 +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; diff --git a/src/test/regress/sql/matview.sql b/src/test/regress/sql/matview.sql index d96175aa26..419eba2075 100644 --- a/src/test/regress/sql/matview.sql +++ b/src/test/regress/sql/matview.sql @@ -236,3 +236,31 @@ SELECT mvtest_func(); SELECT * FROM mvtest1; SELECT * FROM mvtest2; ROLLBACK; + +-- INSERT privileges if relation owner is not allowed to insert. +CREATE SCHEMA matview_schema; +CREATE USER regress_matview_user; +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 +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_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; +RESET SESSION AUTHORIZATION; + +ALTER DEFAULT PRIVILEGES FOR ROLE regress_matview_user + GRANT INSERT ON TABLES TO regress_matview_user; + +DROP SCHEMA matview_schema CASCADE; +DROP USER regress_matview_user; diff --git a/src/test/regress/sql/select_into.sql b/src/test/regress/sql/select_into.sql index a708fef0ea..0faba72bec 100644 --- a/src/test/regress/sql/select_into.sql +++ b/src/test/regress/sql/select_into.sql @@ -27,13 +27,38 @@ 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 + 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%'; -- Error -CREATE TABLE selinto_schema.tmp3 (a,b,c) - AS SELECT oid,relname,relacl FROM pg_class - WHERE relname like '%c%'; -- Error + 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; +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; +-- 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; +-- 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; +EXPLAIN (ANALYZE, COSTS OFF, SUMMARY OFF, TIMING OFF) + CREATE TABLE selinto_schema.tbl_withdata (a) AS + EXECUTE data_sel WITH DATA; +-- 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; RESET SESSION AUTHORIZATION; ALTER DEFAULT PRIVILEGES FOR ROLE regress_selinto_user