Find roles that a member can grant to others, i.e., the role has been granted with ADMIN OPTION. The number of privileges that can be passed on should be as small as possible.
Type
Problem detection (Each row in the result could represent a flaw in the design)
SELECT
role.rolname AS role,
member.rolname AS member,
grantor.rolname AS grantor,
inherit_option,
set_option
FROM pg_auth_members AS pam,
pg_authid AS role,
pg_authid AS member,
pg_authid AS grantor
WHERE pam.roleid=role.oid
AND pam.member=member.oid
AND pam.grantor=grantor.oid
AND member.rolname !~'^pg_'
AND admin_option=TRUE
ORDER BY role, member;
SQL statements that help generate fixes for the identified problem.
SQL Query to Generate Fix
Description
WITH privs AS (SELECT
role.rolname AS role,
member.rolname AS member,
grantor.rolname AS grantor,
inherit_option,
set_option
FROM pg_auth_members AS pam,
pg_authid AS role,
pg_authid AS member,
pg_authid AS grantor
WHERE pam.roleid=role.oid
AND pam.member=member.oid
AND pam.grantor=grantor.oid
AND member.rolname !~'^pg_'
AND admin_option=TRUE)
SELECT format('REVOKE ADMIN OPTION FOR %1$s FROM %2$I;', role, member) AS statements
FROM privs
ORDER BY role, member;
Revoke WITH ADMIN OPTION.
Collections
This query belongs to the following collections:
Name
Description
Find problems automatically
Queries, that results point to problems in the database. Each query in the collection produces an initial assessment. However, a human reviewer has the final say as to whether there is a problem or not .
Categories
This query is classified under the following categories:
Name
Description
Security
Queries of this category provide information about the security measures.