From 4441fc704d7048b2f1f039cc74b72bd23e7e36d0 Mon Sep 17 00:00:00 2001 From: Andrew Dunstan Date: Mon, 28 Nov 2022 11:57:28 -0500 Subject: [PATCH] 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 --- doc/src/sgml/ref/analyze.sgml | 10 +++++++--- doc/src/sgml/ref/vacuum.sgml | 10 +++++++--- doc/src/sgml/user-manag.sgml | 12 ++++++++++++ src/backend/catalog/aclchk.c | 20 +++++++++++++++++++ src/include/catalog/catversion.h | 2 +- src/include/catalog/pg_authid.dat | 10 ++++++++++ src/test/regress/expected/privileges.out | 25 ++++++++++++++++++++++++ src/test/regress/sql/privileges.sql | 24 +++++++++++++++++++++++ 8 files changed, 106 insertions(+), 7 deletions(-) diff --git a/doc/src/sgml/ref/analyze.sgml b/doc/src/sgml/ref/analyze.sgml index 400ea30cd0..16c0b886fd 100644 --- a/doc/src/sgml/ref/analyze.sgml +++ b/doc/src/sgml/ref/analyze.sgml @@ -148,12 +148,16 @@ ANALYZE [ VERBOSE ] [ table_and_columnsNotes - To analyze a table, one must ordinarily be the table's owner or a - superuser or have the ANALYZE privilege on the table. + To analyze a table, one must ordinarily have the ANALYZE + privilege on the table or be the table's owner, a superuser, or a role with + privileges of the + pg_analyze_all_tables + 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 - ANALYZE can only be performed by a superuser.) + ANALYZE can only be performed by superusers and roles + with privileges of pg_analyze_all_tables.) ANALYZE will skip over any tables that the calling user does not have permission to analyze. diff --git a/doc/src/sgml/ref/vacuum.sgml b/doc/src/sgml/ref/vacuum.sgml index 70c0d81346..9cd880ea34 100644 --- a/doc/src/sgml/ref/vacuum.sgml +++ b/doc/src/sgml/ref/vacuum.sgml @@ -356,12 +356,16 @@ VACUUM [ FULL ] [ FREEZE ] [ VERBOSE ] [ ANALYZE ] [ pg_vacuum_all_tables + 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 - VACUUM can only be performed by a superuser.) + VACUUM can only be performed by superusers and roles + with privileges of pg_vacuum_all_tables.) VACUUM will skip over any tables that the calling user does not have permission to vacuum. diff --git a/doc/src/sgml/user-manag.sgml b/doc/src/sgml/user-manag.sgml index 601fff3e6b..2bff4e47d0 100644 --- a/doc/src/sgml/user-manag.sgml +++ b/doc/src/sgml/user-manag.sgml @@ -635,6 +635,18 @@ DROP ROLE doomed_role; the CHECKPOINT command. + + pg_vacuum_all_tables + Allow executing the + VACUUM command on + all tables. + + + pg_analyze_all_tables + Allow executing the + ANALYZE command on + all tables. + diff --git a/src/backend/catalog/aclchk.c b/src/backend/catalog/aclchk.c index 3b5ea3c137..bd967eaa78 100644 --- a/src/backend/catalog/aclchk.c +++ b/src/backend/catalog/aclchk.c @@ -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; } diff --git a/src/include/catalog/catversion.h b/src/include/catalog/catversion.h index 83f8fe46eb..edff430904 100644 --- a/src/include/catalog/catversion.h +++ b/src/include/catalog/catversion.h @@ -57,6 +57,6 @@ */ /* yyyymmddN */ -#define CATALOG_VERSION_NO 202211241 +#define CATALOG_VERSION_NO 202211281 #endif diff --git a/src/include/catalog/pg_authid.dat b/src/include/catalog/pg_authid.dat index 3343a69ddb..2574e2906d 100644 --- a/src/include/catalog/pg_authid.dat +++ b/src/include/catalog/pg_authid.dat @@ -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_' }, ] diff --git a/src/test/regress/expected/privileges.out b/src/test/regress/expected/privileges.out index a2d9572179..7933314fd3 100644 --- a/src/test/regress/expected/privileges.out +++ b/src/test/regress/expected/privileges.out @@ -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; diff --git a/src/test/regress/sql/privileges.sql b/src/test/regress/sql/privileges.sql index dd65c3264e..1bcaaba4eb 100644 --- a/src/test/regress/sql/privileges.sql +++ b/src/test/regress/sql/privileges.sql @@ -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;