Query goal: | Find column 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 about the query: | The query excludes privileges that have been given to superusers because they have the privilege in any case. |
Query type: | Problem detection (Each row in the result could represent a flaw in the design) |
Query reliability: | High (Few or no false-positive results) |
Query license: | MIT License |
Fixing suggestion: | Revoke WITH GRANT OPTION privilege. |
Data source: | INFORMATION_SCHEMA+system catalog |
SQL query: | Click on query to copy it
SELECT cp.grantee, cp.table_schema, cp.table_name, cp.column_name, t.table_type, cp.privilege_type FROM information_schema.column_privileges AS cp INNER JOIN information_schema.tables AS t ON t.table_schema=cp.table_schema AND t.table_name=cp.table_name WHERE cp.is_grantable='YES' AND cp.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 cp.grantee=r.rolname) ORDER BY table_schema, table_name, privilege_type; |
SQL query | Description |
---|---|
WITH grantable_privileges AS (SELECT cp.grantee, cp.table_schema, cp.table_name, cp.column_name, t.table_type, cp.privilege_type FROM information_schema.column_privileges AS cp INNER JOIN information_schema.tables AS t ON t.table_schema=cp.table_schema AND t.table_name=cp.table_name WHERE cp.is_grantable='YES' AND cp.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 cp.grantee=r.rolname)) SELECT format('REVOKE GRANT OPTION FOR %1$s (%2$s) ON TABLE %3$I.%4$I FROM %5$I;', privilege_type, column_name, table_schema, table_name, grantee) AS statements FROM grantable_privileges ORDER BY table_schema, table_name, privilege_type; | Revoke WITH GRANT OPTION privilege. |
Collection name | Collection 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 . |
Category name | Category description |
---|---|
Security | Queries of this category provide information about the security measures. |
Reference |
---|
https://en.wikipedia.org/wiki/Principle_of_least_privilege |
https://www.postgresql.org/docs/current/ddl-priv.html |