Query goal: | PostgreSQL gives by default some privileges to all the present and future database users (PUBLIC). Find usage privileges of collations, domains, foreign data wrappers, foreign servers, and sequences that have been given to PUBLIC. |
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 the usage privileges from PUBLIC. |
Data source: | INFORMATION_SCHEMA+system catalog |
SQL query: | Click on query to copy it
SELECT object_schema, object_name, object_type FROM INFORMATION_SCHEMA.usage_privileges WHERE grantee='PUBLIC' AND object_schema NOT IN (SELECT schema_name FROM INFORMATION_SCHEMA.schemata WHERE schema_name<>'public' AND schema_owner='postgres' AND schema_name IS NOT NULL) UNION SELECT n.nspname AS type_schema, t.typname AS type_name, CASE WHEN typtype='e' THEN 'ENUMERATION TYPE' WHEN typtype='r' THEN 'RANGE TYPE' WHEN typtype='m' THEN 'MULTIRANGE TYPE' END AS type_type FROM pg_type AS t INNER JOIN pg_namespace AS n ON t.typnamespace=n.oid WHERE (array_to_string(typacl,',') IS NULL OR array_to_string(typacl,',') LIKE '%,=U/%') AND typtype IN ('e','r','m') AND n.nspname NOT IN (SELECT schema_name FROM INFORMATION_SCHEMA.schemata WHERE schema_name<>'public' AND schema_owner='postgres' AND schema_name IS NOT NULL) UNION SELECT '-', lanname AS language_name, 'LANGUAGE' AS object_type FROM pg_language WHERE lanispl='t' AND (array_to_string(lanacl,',') IS NULL OR array_to_string(lanacl,',') LIKE '%,=U/%') ORDER BY object_type, object_schema, object_name; |
SQL query | Description |
---|---|
WITH unnecessary_privileges AS (SELECT object_type, object_schema, object_name FROM INFORMATION_SCHEMA.usage_privileges WHERE grantee='PUBLIC' AND object_schema NOT IN (SELECT schema_name FROM INFORMATION_SCHEMA.schemata WHERE schema_name<>'public' AND schema_owner='postgres' AND schema_name IS NOT NULL) UNION SELECT 'TYPE' AS object_type, n.nspname AS type_schema, t.typname AS type_name FROM pg_type AS t INNER JOIN pg_namespace AS n ON t.typnamespace=n.oid WHERE (array_to_string(typacl,',') IS NULL OR array_to_string(typacl,',') LIKE '%,=U/%') AND typtype IN ('e','r','m') AND n.nspname NOT IN (SELECT schema_name FROM INFORMATION_SCHEMA.schemata WHERE schema_name<>'public' AND schema_owner='postgres' AND schema_name IS NOT NULL)) SELECT format('REVOKE USAGE ON %1$s %2$I.%3$I FROM PUBLIC;', object_type, object_schema, object_name) AS statements FROM unnecessary_privileges ORDER BY object_type, object_schema, object_name; | Revoke the usage privileges from PUBLIC. |
WITH unnecessary_privileges AS (SELECT lanname AS language_name FROM pg_language WHERE lanispl='t' AND (array_to_string(lanacl,',') IS NULL OR array_to_string(lanacl,',') LIKE '%,=U/%')) SELECT format('REVOKE USAGE ON LANGUAGE %1$I FROM PUBLIC;', language_name) AS statements FROM unnecessary_privileges ORDER BY language_name; | Revoke language USAGE privilege from PUBLIC. |
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 |
---|---|
Domains | Queries of this category provide information about reusable specifications of column properties. |
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 |