Provide non-superuser predefined roles for vacuum and analyze

This provides two new predefined roles: pg_vacuum_all_tables and
pg_analyze_all_tables. Roles which have been granted these roles can
perform vacuum or analyse respectively on any or all tables as if they
were a superuser. This removes the need to grant superuser privilege to
roles just so they can perform vacuum and/or analyze.

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
This commit is contained in:
Andrew Dunstan 2022-11-28 11:57:28 -05:00
parent b5d6382496
commit 4441fc704d
8 changed files with 106 additions and 7 deletions

View File

@ -148,12 +148,16 @@ ANALYZE [ VERBOSE ] [ <replaceable class="parameter">table_and_columns</replacea
<title>Notes</title>
<para>
To analyze a table, one must ordinarily be the table's owner or a
superuser or have the <literal>ANALYZE</literal> privilege on the table.
To analyze a table, one must ordinarily have the <literal>ANALYZE</literal>
privilege on the table or be the table's owner, a superuser, or a role with
privileges of the
<link linkend="predefined-roles-table"><literal>pg_analyze_all_tables</literal></link>
role.
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.)
<command>ANALYZE</command> can only be performed by superusers and roles
with privileges of <literal>pg_analyze_all_tables</literal>.)
<command>ANALYZE</command> will skip over any tables that the calling user
does not have permission to analyze.
</para>

View File

@ -356,12 +356,16 @@ VACUUM [ FULL ] [ FREEZE ] [ VERBOSE ] [ ANALYZE ] [ <replaceable class="paramet
<title>Notes</title>
<para>
To vacuum a table, one must ordinarily be the table's owner or a
superuser or have the <literal>VACUUM</literal> privilege on the table.
To vacuum a table, one must ordinarily have the <literal>VACUUM</literal>
privilege on the table or be the table's owner, a superuser, or a role with
privileges of the
<link linkend="predefined-roles-table"><literal>pg_vacuum_all_tables</literal></link>
role.
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.)
<command>VACUUM</command> can only be performed by superusers and roles
with privileges of <literal>pg_vacuum_all_tables</literal>.)
<command>VACUUM</command> will skip over any tables that the calling user
does not have permission to vacuum.
</para>

View File

@ -635,6 +635,18 @@ DROP ROLE doomed_role;
the <link linkend="sql-checkpoint"><command>CHECKPOINT</command></link>
command.</entry>
</row>
<row>
<entry>pg_vacuum_all_tables</entry>
<entry>Allow executing the
<link linkend="sql-vacuum"><command>VACUUM</command></link> command on
all tables.</entry>
</row>
<row>
<entry>pg_analyze_all_tables</entry>
<entry>Allow executing the
<link linkend="sql-analyze"><command>ANALYZE</command></link> command on
all tables.</entry>
</row>
</tbody>
</tgroup>
</table>

View File

@ -4202,6 +4202,26 @@ pg_class_aclmask_ext(Oid table_oid, Oid roleid, AclMode mask,
has_privs_of_role(roleid, ROLE_PG_WRITE_ALL_DATA))
result |= (mask & (ACL_INSERT | ACL_UPDATE | ACL_DELETE));
/*
* Check if ACL_VACUUM is being checked and, if so, and not already set as
* part of the result, then check if the user is a member of the
* pg_vacuum_all_tables role, which allows VACUUM on all relations.
*/
if (mask & ACL_VACUUM &&
!(result & ACL_VACUUM) &&
has_privs_of_role(roleid, ROLE_PG_VACUUM_ALL_TABLES))
result |= ACL_VACUUM;
/*
* Check if ACL_ANALYZE is being checked and, if so, and not already set as
* part of the result, then check if the user is a member of the
* pg_analyze_all_tables role, which allows ANALYZE on all relations.
*/
if (mask & ACL_ANALYZE &&
!(result & ACL_ANALYZE) &&
has_privs_of_role(roleid, ROLE_PG_ANALYZE_ALL_TABLES))
result |= ACL_ANALYZE;
return result;
}

View File

@ -57,6 +57,6 @@
*/
/* yyyymmddN */
#define CATALOG_VERSION_NO 202211241
#define CATALOG_VERSION_NO 202211281
#endif

View File

@ -84,5 +84,15 @@
rolcreaterole => 'f', rolcreatedb => 'f', rolcanlogin => 'f',
rolreplication => 'f', rolbypassrls => 'f', rolconnlimit => '-1',
rolpassword => '_null_', rolvaliduntil => '_null_' },
{ oid => '4549', oid_symbol => 'ROLE_PG_VACUUM_ALL_TABLES',
rolname => 'pg_vacuum_all_tables', rolsuper => 'f', rolinherit => 't',
rolcreaterole => 'f', rolcreatedb => 'f', rolcanlogin => 'f',
rolreplication => 'f', rolbypassrls => 'f', rolconnlimit => '-1',
rolpassword => '_null_', rolvaliduntil => '_null_' },
{ oid => '4550', oid_symbol => 'ROLE_PG_ANALYZE_ALL_TABLES',
rolname => 'pg_analyze_all_tables', rolsuper => 'f', rolinherit => 't',
rolcreaterole => 'f', rolcreatedb => 'f', rolcanlogin => 'f',
rolreplication => 'f', rolbypassrls => 'f', rolconnlimit => '-1',
rolpassword => '_null_', rolvaliduntil => '_null_' },
]

View File

@ -2854,6 +2854,9 @@ CREATE ROLE regress_no_priv;
CREATE ROLE regress_only_vacuum;
CREATE ROLE regress_only_analyze;
CREATE ROLE regress_both;
CREATE ROLE regress_only_vacuum_all IN ROLE pg_vacuum_all_tables;
CREATE ROLE regress_only_analyze_all IN ROLE pg_analyze_all_tables;
CREATE ROLE regress_both_all IN ROLE pg_vacuum_all_tables, pg_analyze_all_tables;
CREATE TABLE vacanalyze_test (a INT);
GRANT VACUUM ON vacanalyze_test TO regress_only_vacuum, regress_both;
GRANT ANALYZE ON vacanalyze_test TO regress_only_analyze, regress_both;
@ -2884,8 +2887,30 @@ VACUUM vacanalyze_test;
ANALYZE vacanalyze_test;
VACUUM (ANALYZE) vacanalyze_test;
RESET ROLE;
SET ROLE regress_only_vacuum_all;
VACUUM vacanalyze_test;
ANALYZE vacanalyze_test;
WARNING: permission denied to analyze "vacanalyze_test", skipping it
VACUUM (ANALYZE) vacanalyze_test;
WARNING: permission denied to analyze "vacanalyze_test", skipping it
RESET ROLE;
SET ROLE regress_only_analyze_all;
VACUUM vacanalyze_test;
WARNING: permission denied to vacuum "vacanalyze_test", skipping it
ANALYZE vacanalyze_test;
VACUUM (ANALYZE) vacanalyze_test;
WARNING: permission denied to vacuum "vacanalyze_test", skipping it
RESET ROLE;
SET ROLE regress_both_all;
VACUUM vacanalyze_test;
ANALYZE vacanalyze_test;
VACUUM (ANALYZE) vacanalyze_test;
RESET ROLE;
DROP TABLE vacanalyze_test;
DROP ROLE regress_no_priv;
DROP ROLE regress_only_vacuum;
DROP ROLE regress_only_analyze;
DROP ROLE regress_both;
DROP ROLE regress_only_vacuum_all;
DROP ROLE regress_only_analyze_all;
DROP ROLE regress_both_all;

View File

@ -1858,6 +1858,9 @@ CREATE ROLE regress_no_priv;
CREATE ROLE regress_only_vacuum;
CREATE ROLE regress_only_analyze;
CREATE ROLE regress_both;
CREATE ROLE regress_only_vacuum_all IN ROLE pg_vacuum_all_tables;
CREATE ROLE regress_only_analyze_all IN ROLE pg_analyze_all_tables;
CREATE ROLE regress_both_all IN ROLE pg_vacuum_all_tables, pg_analyze_all_tables;
CREATE TABLE vacanalyze_test (a INT);
GRANT VACUUM ON vacanalyze_test TO regress_only_vacuum, regress_both;
@ -1887,8 +1890,29 @@ ANALYZE vacanalyze_test;
VACUUM (ANALYZE) vacanalyze_test;
RESET ROLE;
SET ROLE regress_only_vacuum_all;
VACUUM vacanalyze_test;
ANALYZE vacanalyze_test;
VACUUM (ANALYZE) vacanalyze_test;
RESET ROLE;
SET ROLE regress_only_analyze_all;
VACUUM vacanalyze_test;
ANALYZE vacanalyze_test;
VACUUM (ANALYZE) vacanalyze_test;
RESET ROLE;
SET ROLE regress_both_all;
VACUUM vacanalyze_test;
ANALYZE vacanalyze_test;
VACUUM (ANALYZE) vacanalyze_test;
RESET ROLE;
DROP TABLE vacanalyze_test;
DROP ROLE regress_no_priv;
DROP ROLE regress_only_vacuum;
DROP ROLE regress_only_analyze;
DROP ROLE regress_both;
DROP ROLE regress_only_vacuum_all;
DROP ROLE regress_only_analyze_all;
DROP ROLE regress_both_all;