Skip to content

Commit

Permalink
Provide per-table permissions for vacuum and analyze.
Browse files Browse the repository at this point in the history
Currently a table can only be vacuumed or analyzed by its owner or
a superuser. This can now be extended to any user by means of an
appropriate GRANT.

Nathan Bossart

Reviewed by: Bharath Rupireddy, Kyotaro Horiguchi, Stephen Frost, Robert
Haas, Mark Dilger, Tom Lane, Corey Huinker, David G. Johnston, Michael
Paquier.

Discussion: https://postgr.es/m/20220722203735.GB3996698@nathanxps13
  • Loading branch information
adunstan committed Nov 28, 2022
1 parent 1f059a4 commit b5d6382
Show file tree
Hide file tree
Showing 24 changed files with 274 additions and 113 deletions.
49 changes: 39 additions & 10 deletions doc/src/sgml/ddl.sgml
Original file line number Diff line number Diff line change
Expand Up @@ -1691,8 +1691,9 @@ ALTER TABLE products RENAME TO items;
<literal>INSERT</literal>, <literal>UPDATE</literal>, <literal>DELETE</literal>,
<literal>TRUNCATE</literal>, <literal>REFERENCES</literal>, <literal>TRIGGER</literal>,
<literal>CREATE</literal>, <literal>CONNECT</literal>, <literal>TEMPORARY</literal>,
<literal>EXECUTE</literal>, <literal>USAGE</literal>, <literal>SET</literal>
and <literal>ALTER SYSTEM</literal>.
<literal>EXECUTE</literal>, <literal>USAGE</literal>, <literal>SET</literal>,
<literal>ALTER SYSTEM</literal>, <literal>VACUUM</literal>, and
<literal>ANALYZE</literal>.
The privileges applicable to a particular
object vary depending on the object's type (table, function, etc.).
More detail about the meanings of these privileges appears below.
Expand Down Expand Up @@ -1982,7 +1983,25 @@ REVOKE ALL ON accounts FROM PUBLIC;
</para>
</listitem>
</varlistentry>
</variablelist>

<varlistentry>
<term><literal>VACUUM</literal></term>
<listitem>
<para>
Allows <command>VACUUM</command> on a relation.
</para>
</listitem>
</varlistentry>

<varlistentry>
<term><literal>ANALYZE</literal></term>
<listitem>
<para>
Allows <command>ANALYZE</command> on a relation.
</para>
</listitem>
</varlistentry>
</variablelist>

The privileges required by other commands are listed on the
reference page of the respective command.
Expand Down Expand Up @@ -2131,6 +2150,16 @@ REVOKE ALL ON accounts FROM PUBLIC;
<entry><literal>A</literal></entry>
<entry><literal>PARAMETER</literal></entry>
</row>
<row>
<entry><literal>VACUUM</literal></entry>
<entry><literal>v</literal></entry>
<entry><literal>TABLE</literal></entry>
</row>
<row>
<entry><literal>ANALYZE</literal></entry>
<entry><literal>z</literal></entry>
<entry><literal>TABLE</literal></entry>
</row>
</tbody>
</tgroup>
</table>
Expand Down Expand Up @@ -2221,7 +2250,7 @@ REVOKE ALL ON accounts FROM PUBLIC;
</row>
<row>
<entry><literal>TABLE</literal> (and table-like objects)</entry>
<entry><literal>arwdDxt</literal></entry>
<entry><literal>arwdDxtvz</literal></entry>
<entry>none</entry>
<entry><literal>\dp</literal></entry>
</row>
Expand Down Expand Up @@ -2279,12 +2308,12 @@ GRANT SELECT (col1), UPDATE (col1) ON mytable TO miriam_rw;
would show:
<programlisting>
=&gt; \dp mytable
Access privileges
Schema | Name | Type | Access privileges | Column privileges | Policies
--------+---------+-------+-----------------------+-----------------------+----------
public | mytable | table | miriam=arwdDxt/miriam+| col1: +|
| | | =r/miriam +| miriam_rw=rw/miriam |
| | | admin=arw/miriam | |
Access privileges
Schema | Name | Type | Access privileges | Column privileges | Policies
--------+---------+-------+-------------------------+-----------------------+----------
public | mytable | table | miriam=arwdDxtvz/miriam+| col1: +|
| | | =r/miriam +| miriam_rw=rw/miriam |
| | | admin=arw/miriam | |
(1 row)
</programlisting>
</para>
Expand Down
3 changes: 2 additions & 1 deletion doc/src/sgml/func.sgml
Original file line number Diff line number Diff line change
Expand Up @@ -22978,7 +22978,8 @@ SELECT has_function_privilege('joeuser', 'myfunc(int, text)', 'execute');
are <literal>SELECT</literal>, <literal>INSERT</literal>,
<literal>UPDATE</literal>, <literal>DELETE</literal>,
<literal>TRUNCATE</literal>, <literal>REFERENCES</literal>,
and <literal>TRIGGER</literal>.
<literal>TRIGGER</literal>, <literal>VACUUM</literal> and
<literal>ANALYZE</literal>.
</para></entry>
</row>

Expand Down
4 changes: 2 additions & 2 deletions doc/src/sgml/ref/alter_default_privileges.sgml
Original file line number Diff line number Diff line change
Expand Up @@ -28,7 +28,7 @@ ALTER DEFAULT PRIVILEGES

<phrase>where <replaceable class="parameter">abbreviated_grant_or_revoke</replaceable> is one of:</phrase>

GRANT { { SELECT | INSERT | UPDATE | DELETE | TRUNCATE | REFERENCES | TRIGGER }
GRANT { { SELECT | INSERT | UPDATE | DELETE | TRUNCATE | REFERENCES | TRIGGER | VACUUM | ANALYZE }
[, ...] | ALL [ PRIVILEGES ] }
ON TABLES
TO { [ GROUP ] <replaceable class="parameter">role_name</replaceable> | PUBLIC } [, ...] [ WITH GRANT OPTION ]
Expand All @@ -51,7 +51,7 @@ GRANT { USAGE | CREATE | ALL [ PRIVILEGES ] }
TO { [ GROUP ] <replaceable class="parameter">role_name</replaceable> | PUBLIC } [, ...] [ WITH GRANT OPTION ]

REVOKE [ GRANT OPTION FOR ]
{ { SELECT | INSERT | UPDATE | DELETE | TRUNCATE | REFERENCES | TRIGGER }
{ { SELECT | INSERT | UPDATE | DELETE | TRUNCATE | REFERENCES | TRIGGER | VACUUM | ANALYZE }
[, ...] | ALL [ PRIVILEGES ] }
ON TABLES
FROM { [ GROUP ] <replaceable class="parameter">role_name</replaceable> | PUBLIC } [, ...]
Expand Down
3 changes: 2 additions & 1 deletion doc/src/sgml/ref/analyze.sgml
Original file line number Diff line number Diff line change
Expand Up @@ -149,7 +149,8 @@ ANALYZE [ VERBOSE ] [ <replaceable class="parameter">table_and_columns</replacea

<para>
To analyze a table, one must ordinarily be the table's owner or a
superuser. However, database owners are allowed to
superuser or have the <literal>ANALYZE</literal> privilege on the table.
However, database owners are allowed to
analyze all tables in their databases, except shared catalogs.
(The restriction for shared catalogs means that a true database-wide
<command>ANALYZE</command> can only be performed by a superuser.)
Expand Down
4 changes: 3 additions & 1 deletion doc/src/sgml/ref/grant.sgml
Original file line number Diff line number Diff line change
Expand Up @@ -21,7 +21,7 @@ PostgreSQL documentation

<refsynopsisdiv>
<synopsis>
GRANT { { SELECT | INSERT | UPDATE | DELETE | TRUNCATE | REFERENCES | TRIGGER }
GRANT { { SELECT | INSERT | UPDATE | DELETE | TRUNCATE | REFERENCES | TRIGGER | VACUUM | ANALYZE }
[, ...] | ALL [ PRIVILEGES ] }
ON { [ TABLE ] <replaceable class="parameter">table_name</replaceable> [, ...]
| ALL TABLES IN SCHEMA <replaceable class="parameter">schema_name</replaceable> [, ...] }
Expand Down Expand Up @@ -193,6 +193,8 @@ GRANT <replaceable class="parameter">role_name</replaceable> [, ...] TO <replace
<term><literal>USAGE</literal></term>
<term><literal>SET</literal></term>
<term><literal>ALTER SYSTEM</literal></term>
<term><literal>VACUUM</literal></term>
<term><literal>ANALYZE</literal></term>
<listitem>
<para>
Specific types of privileges, as defined in <xref linkend="ddl-priv"/>.
Expand Down
2 changes: 1 addition & 1 deletion doc/src/sgml/ref/revoke.sgml
Original file line number Diff line number Diff line change
Expand Up @@ -22,7 +22,7 @@ PostgreSQL documentation
<refsynopsisdiv>
<synopsis>
REVOKE [ GRANT OPTION FOR ]
{ { SELECT | INSERT | UPDATE | DELETE | TRUNCATE | REFERENCES | TRIGGER }
{ { SELECT | INSERT | UPDATE | DELETE | TRUNCATE | REFERENCES | TRIGGER | VACUUM | ANALYZE }
[, ...] | ALL [ PRIVILEGES ] }
ON { [ TABLE ] <replaceable class="parameter">table_name</replaceable> [, ...]
| ALL TABLES IN SCHEMA <replaceable>schema_name</replaceable> [, ...] }
Expand Down
3 changes: 2 additions & 1 deletion doc/src/sgml/ref/vacuum.sgml
Original file line number Diff line number Diff line change
Expand Up @@ -357,7 +357,8 @@ VACUUM [ FULL ] [ FREEZE ] [ VERBOSE ] [ ANALYZE ] [ <replaceable class="paramet

<para>
To vacuum a table, one must ordinarily be the table's owner or a
superuser. However, database owners are allowed to
superuser or have the <literal>VACUUM</literal> privilege on the table.
However, database owners are allowed to
vacuum all tables in their databases, except shared catalogs.
(The restriction for shared catalogs means that a true database-wide
<command>VACUUM</command> can only be performed by a superuser.)
Expand Down
8 changes: 8 additions & 0 deletions src/backend/catalog/aclchk.c
Original file line number Diff line number Diff line change
Expand Up @@ -3420,6 +3420,10 @@ string_to_privilege(const char *privname)
return ACL_SET;
if (strcmp(privname, "alter system") == 0)
return ACL_ALTER_SYSTEM;
if (strcmp(privname, "vacuum") == 0)
return ACL_VACUUM;
if (strcmp(privname, "analyze") == 0)
return ACL_ANALYZE;
if (strcmp(privname, "rule") == 0)
return 0; /* ignore old RULE privileges */
ereport(ERROR,
Expand Down Expand Up @@ -3461,6 +3465,10 @@ privilege_to_string(AclMode privilege)
return "SET";
case ACL_ALTER_SYSTEM:
return "ALTER SYSTEM";
case ACL_VACUUM:
return "VACUUM";
case ACL_ANALYZE:
return "ANALYZE";
default:
elog(ERROR, "unrecognized privilege: %d", (int) privilege);
}
Expand Down
13 changes: 6 additions & 7 deletions src/backend/commands/analyze.c
Original file line number Diff line number Diff line change
Expand Up @@ -159,16 +159,15 @@ analyze_rel(Oid relid, RangeVar *relation,
return;

/*
* Check if relation needs to be skipped based on ownership. This check
* Check if relation needs to be skipped based on privileges. This check
* happens also when building the relation list to analyze for a manual
* operation, and needs to be done additionally here as ANALYZE could
* happen across multiple transactions where relation ownership could have
* changed in-between. Make sure to generate only logs for ANALYZE in
* this case.
* happen across multiple transactions where privileges could have changed
* in-between. Make sure to generate only logs for ANALYZE in this case.
*/
if (!vacuum_is_relation_owner(RelationGetRelid(onerel),
onerel->rd_rel,
params->options & VACOPT_ANALYZE))
if (!vacuum_is_permitted_for_relation(RelationGetRelid(onerel),
onerel->rd_rel,
VACOPT_ANALYZE))
{
relation_close(onerel, ShareUpdateExclusiveLock);
return;
Expand Down
62 changes: 33 additions & 29 deletions src/backend/commands/vacuum.c
Original file line number Diff line number Diff line change
Expand Up @@ -547,32 +547,35 @@ vacuum(List *relations, VacuumParams *params,
}

/*
* Check if a given relation can be safely vacuumed or analyzed. If the
* user is not the relation owner, issue a WARNING log message and return
* false to let the caller decide what to do with this relation. This
* routine is used to decide if a relation can be processed for VACUUM or
* ANALYZE.
* Check if the current user has privileges to vacuum or analyze the relation.
* If not, issue a WARNING log message and return false to let the caller
* decide what to do with this relation. This routine is used to decide if a
* relation can be processed for VACUUM or ANALYZE.
*/
bool
vacuum_is_relation_owner(Oid relid, Form_pg_class reltuple, bits32 options)
vacuum_is_permitted_for_relation(Oid relid, Form_pg_class reltuple,
bits32 options)
{
char *relname;
AclMode mode = 0;

Assert((options & (VACOPT_VACUUM | VACOPT_ANALYZE)) != 0);

/*
* Check permissions.
*
* We allow the user to vacuum or analyze a table if he is superuser, the
* table owner, or the database owner (but in the latter case, only if
* it's not a shared relation). object_ownercheck includes the
* superuser case.
*
* Note we choose to treat permissions failure as a WARNING and keep
* trying to vacuum or analyze the rest of the DB --- is this appropriate?
* A role has privileges to vacuum or analyze the relation if any of the
* following are true:
* - the role is a superuser
* - the role owns the relation
* - the role owns the current database and the relation is not shared
* - the role has been granted privileges to vacuum/analyze the relation
*/
if (options & VACOPT_VACUUM)
mode |= ACL_VACUUM;
if (options & VACOPT_ANALYZE)
mode |= ACL_ANALYZE;
if (object_ownercheck(RelationRelationId, relid, GetUserId()) ||
(object_ownercheck(DatabaseRelationId, MyDatabaseId, GetUserId()) && !reltuple->relisshared))
(object_ownercheck(DatabaseRelationId, MyDatabaseId, GetUserId()) && !reltuple->relisshared) ||
pg_class_aclcheck(relid, GetUserId(), mode) == ACLCHECK_OK)
return true;

relname = NameStr(reltuple->relname);
Expand Down Expand Up @@ -787,10 +790,10 @@ expand_vacuum_rel(VacuumRelation *vrel, int options)
classForm = (Form_pg_class) GETSTRUCT(tuple);

/*
* Make a returnable VacuumRelation for this rel if user is a proper
* owner.
* Make a returnable VacuumRelation for this rel if the user has the
* required privileges.
*/
if (vacuum_is_relation_owner(relid, classForm, options))
if (vacuum_is_permitted_for_relation(relid, classForm, options))
{
oldcontext = MemoryContextSwitchTo(vac_context);
vacrels = lappend(vacrels, makeVacuumRelation(vrel->relation,
Expand Down Expand Up @@ -877,7 +880,7 @@ get_all_vacuum_rels(int options)
Oid relid = classForm->oid;

/* check permissions of relation */
if (!vacuum_is_relation_owner(relid, classForm, options))
if (!vacuum_is_permitted_for_relation(relid, classForm, options))
continue;

/*
Expand Down Expand Up @@ -1797,7 +1800,9 @@ vac_truncate_clog(TransactionId frozenXID,
* be stale.
*
* Returns true if it's okay to proceed with a requested ANALYZE
* operation on this table.
* operation on this table. Note that if vacuuming fails because the user
* does not have the required privileges, this function returns true since
* the user might have been granted privileges to ANALYZE the relation.
*
* Doing one heap at a time incurs extra overhead, since we need to
* check that the heap exists again just before we vacuum it. The
Expand Down Expand Up @@ -1889,21 +1894,20 @@ vacuum_rel(Oid relid, RangeVar *relation, VacuumParams *params)
}

/*
* Check if relation needs to be skipped based on ownership. This check
* Check if relation needs to be skipped based on privileges. This check
* happens also when building the relation list to vacuum for a manual
* operation, and needs to be done additionally here as VACUUM could
* happen across multiple transactions where relation ownership could have
* changed in-between. Make sure to only generate logs for VACUUM in this
* case.
* happen across multiple transactions where privileges could have changed
* in-between. Make sure to only generate logs for VACUUM in this case.
*/
if (!vacuum_is_relation_owner(RelationGetRelid(rel),
rel->rd_rel,
params->options & VACOPT_VACUUM))
if (!vacuum_is_permitted_for_relation(RelationGetRelid(rel),
rel->rd_rel,
VACOPT_VACUUM))
{
relation_close(rel, lmode);
PopActiveSnapshot();
CommitTransactionCommand();
return false;
return true; /* user might have the ANALYZE privilege */
}

/*
Expand Down
7 changes: 7 additions & 0 deletions src/backend/parser/gram.y
Original file line number Diff line number Diff line change
Expand Up @@ -7482,6 +7482,13 @@ privilege: SELECT opt_column_list
n->cols = NIL;
$$ = n;
}
| analyze_keyword
{
AccessPriv *n = makeNode(AccessPriv);
n->priv_name = pstrdup("analyze");
n->cols = NIL;
$$ = n;
}
| ColId opt_column_list
{
AccessPriv *n = makeNode(AccessPriv);
Expand Down
16 changes: 16 additions & 0 deletions src/backend/utils/adt/acl.c
Original file line number Diff line number Diff line change
Expand Up @@ -321,6 +321,12 @@ aclparse(const char *s, AclItem *aip)
case ACL_ALTER_SYSTEM_CHR:
read = ACL_ALTER_SYSTEM;
break;
case ACL_VACUUM_CHR:
read = ACL_VACUUM;
break;
case ACL_ANALYZE_CHR:
read = ACL_ANALYZE;
break;
case 'R': /* ignore old RULE privileges */
read = 0;
break;
Expand Down Expand Up @@ -1595,6 +1601,8 @@ makeaclitem(PG_FUNCTION_ARGS)
{"CONNECT", ACL_CONNECT},
{"SET", ACL_SET},
{"ALTER SYSTEM", ACL_ALTER_SYSTEM},
{"VACUUM", ACL_VACUUM},
{"ANALYZE", ACL_ANALYZE},
{"RULE", 0}, /* ignore old RULE privileges */
{NULL, 0}
};
Expand Down Expand Up @@ -1703,6 +1711,10 @@ convert_aclright_to_string(int aclright)
return "SET";
case ACL_ALTER_SYSTEM:
return "ALTER SYSTEM";
case ACL_VACUUM:
return "VACUUM";
case ACL_ANALYZE:
return "ANALYZE";
default:
elog(ERROR, "unrecognized aclright: %d", aclright);
return NULL;
Expand Down Expand Up @@ -2012,6 +2024,10 @@ convert_table_priv_string(text *priv_type_text)
{"REFERENCES WITH GRANT OPTION", ACL_GRANT_OPTION_FOR(ACL_REFERENCES)},
{"TRIGGER", ACL_TRIGGER},
{"TRIGGER WITH GRANT OPTION", ACL_GRANT_OPTION_FOR(ACL_TRIGGER)},
{"VACUUM", ACL_VACUUM},
{"VACUUM WITH GRANT OPTION", ACL_GRANT_OPTION_FOR(ACL_VACUUM)},
{"ANALYZE", ACL_ANALYZE},
{"ANALYZE WITH GRANT OPTION", ACL_GRANT_OPTION_FOR(ACL_ANALYZE)},
{"RULE", 0}, /* ignore old RULE privileges */
{"RULE WITH GRANT OPTION", 0},
{NULL, 0}
Expand Down
2 changes: 2 additions & 0 deletions src/bin/pg_dump/dumputils.c
Original file line number Diff line number Diff line change
Expand Up @@ -457,6 +457,8 @@ do { \
CONVERT_PRIV('d', "DELETE");
CONVERT_PRIV('t', "TRIGGER");
CONVERT_PRIV('D', "TRUNCATE");
CONVERT_PRIV('v', "VACUUM");
CONVERT_PRIV('z', "ANALYZE");
}
}

Expand Down
2 changes: 1 addition & 1 deletion src/bin/pg_dump/t/002_pg_dump.pl
Original file line number Diff line number Diff line change
Expand Up @@ -566,7 +566,7 @@
\QREVOKE ALL ON TABLES FROM regress_dump_test_role;\E\n
\QALTER DEFAULT PRIVILEGES \E
\QFOR ROLE regress_dump_test_role \E
\QGRANT INSERT,REFERENCES,DELETE,TRIGGER,TRUNCATE,UPDATE ON TABLES TO regress_dump_test_role;\E
\QGRANT INSERT,REFERENCES,DELETE,TRIGGER,TRUNCATE,VACUUM,ANALYZE,UPDATE ON TABLES TO regress_dump_test_role;\E
/xm,
like => { %full_runs, section_post_data => 1, },
unlike => { no_privs => 1, },
Expand Down
Loading

0 comments on commit b5d6382

Please sign in to comment.