Find table privileges that the carrier of the privilege can in turn grant to others, i.e., the privileges have been given WITH GRANT OPTION. The number of privileges that can be passed on should be as small as possible.
Notes
The query excludes privileges that have been given to superusers because they have the privilege in any case.
Type
Problem detection (Each row in the result could represent a flaw in the design)
SELECT tp.grantee, tp.table_schema, tp.table_name, t.table_type, tp.privilege_type
FROM information_schema.table_privileges AS tp INNER JOIN information_schema.tables AS t
USING (table_schema, table_name)
WHERE tp.is_grantable='YES' AND tp.table_schema <>ALL (SELECT schema_name
FROM INFORMATION_SCHEMA.schemata
WHERE schema_name<>'public' AND
schema_owner='postgres' AND schema_name IS NOT NULL)
AND NOT EXISTS (SELECT 1
FROM pg_catalog.pg_roles r
WHERE rolsuper=TRUE AND tp.grantee=r.rolname)
ORDER BY table_schema, table_name, privilege_type;
SQL statements that help generate fixes for the identified problem.
SQL Query to Generate Fix
Description
WITH grantable_privileges AS (SELECT tp.grantee, tp.table_schema, tp.table_name, t.table_type, tp.privilege_type
FROM information_schema.table_privileges AS tp INNER JOIN information_schema.tables AS t
USING (table_schema, table_name)
WHERE tp.is_grantable='YES' AND tp.table_schema <>ALL (SELECT schema_name
FROM INFORMATION_SCHEMA.schemata
WHERE schema_name<>'public' AND
schema_owner='postgres' AND schema_name IS NOT NULL)
AND NOT EXISTS (SELECT 1
FROM pg_catalog.pg_roles r
WHERE rolsuper=TRUE AND tp.grantee=r.rolname))
SELECT format('REVOKE GRANT OPTION FOR %1$s ON TABLE %2$I.%3$I FROM %4$I;', privilege_type, table_schema, table_name, grantee) AS statements
FROM grantable_privileges
ORDER BY table_schema, table_name, privilege_type;
Revoke WITH GRANT OPTION privilege.
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
Derived tables
Queries of this category provide information about the derived tables (views, materialized views), which are used to implement virtual data layer.
Security
Queries of this category provide information about the security measures.