The list of all the queries

Table, routine, and usage privileges that have been granted to a superuser

Query goal: Find table, routine, and usage privileges that have been granted to a superuser. Superuser can do anything in the database and thus does not need the privileges. The result is a sign that perhaps the executed GRANT statements were incorrect (wrong username) or the grantee later got superuser status (that it shouldn't have).
Notes about the query: The query does consider the routines that are a part of an extension. There could be multiple routines with the same name but with different parameters in the same schema (overloading). Thus, for the unique identification of the routine it is necessary to present also its parameters in addition to the schema name and routine name.
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 privileges or remove superuser status from the grantee.
Data source: INFORMATION_SCHEMA+system catalog
SQL query: Click on query to copy it

SELECT grantee AS superuser, table_schema AS object_schema, table_name AS object_name, table_type AS object_type, privilege_type
FROM information_schema.table_privileges INNER JOIN information_schema.tables USING (table_schema, table_name)
WHERE table_schema NOT IN (SELECT schema_name
FROM INFORMATION_SCHEMA.schemata
WHERE schema_name<>'public' AND
schema_owner='postgres' AND schema_name IS NOT NULL)
AND grantee IN (SELECT usename
FROM pg_user
WHERE usesuper=TRUE)
AND grantee<>grantor
UNION SELECT grantee, specific_schema, r.routine_name || '(' || pg_get_function_identity_arguments(translate(substring(specific_name,'_[0-9]+$'),'_','')::int::oid) || ')' AS routine, r.routine_type, privilege_type
FROM information_schema.routine_privileges INNER JOIN information_schema.routines AS r USING (specific_schema, specific_name)
WHERE r.routine_schema NOT IN (SELECT schema_name
FROM INFORMATION_SCHEMA.schemata
WHERE schema_name<>'public' AND
schema_owner='postgres' AND schema_name IS NOT NULL)
AND grantee IN (SELECT usename
FROM pg_user
WHERE usesuper=TRUE)
AND grantee<>grantor
UNION SELECT grantee, object_schema, object_name, object_type, privilege_type
FROM information_schema.usage_privileges
WHERE 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)
AND grantee IN (SELECT usename
FROM pg_user
WHERE usesuper=TRUE)
AND grantee<>grantor
ORDER BY superuser, object_type, privilege_type, object_schema, object_name;

SQL statements for generating SQL statements that help us to fix the problem

SQL queryDescription
SELECT format('REVOKE %1$s ON TABLE %2$I.%3$I FROM %4$I;', privilege_type, table_schema, table_name, grantee) AS statements
FROM information_schema.table_privileges INNER JOIN information_schema.tables USING (table_schema, table_name)
WHERE table_schema NOT IN (SELECT schema_name
FROM INFORMATION_SCHEMA.schemata
WHERE schema_name<>'public' AND
schema_owner='postgres' AND schema_name IS NOT NULL)
AND grantee IN (SELECT usename
FROM pg_user
WHERE usesuper=TRUE)
AND grantee<>grantor
ORDER BY grantee, table_type, privilege_type, table_schema, table_name;
Revoke the table privileges.
SELECT format('REVOKE %1$s ON ROUTINE %2$I.%3$I(%4$s) FROM %5$I;', privilege_type, specific_schema, r.routine_name , pg_get_function_identity_arguments(translate(substring(specific_name,'_[0-9]+$'),'_','')::int::oid), grantee) AS statements
FROM information_schema.routine_privileges INNER JOIN information_schema.routines AS r USING (specific_schema, specific_name)
WHERE r.routine_schema NOT IN (SELECT schema_name
FROM INFORMATION_SCHEMA.schemata
WHERE schema_name<>'public' AND
schema_owner='postgres' AND schema_name IS NOT NULL)
AND grantee IN (SELECT usename
FROM pg_user
WHERE usesuper=TRUE)
AND grantee<>grantor
ORDER BY grantee, routine_type, privilege_type, r.routine_schema, r.routine_name;
Revoke the routine privileges.
SELECT format('REVOKE %1$s ON %2$s %3$I.%4$I FROM %5$I;', privilege_type, object_type, object_schema, object_name, grantee) AS statements
FROM information_schema.usage_privileges
WHERE 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)
AND grantee IN (SELECT usename
FROM pg_user
WHERE usesuper=TRUE)
AND grantee<>grantor
ORDER BY grantee, object_type, privilege_type, object_schema, object_name;
Revoke the usage privileges.

Collections where the query belongs to

Collection nameCollection description
Find problems automaticallyQueries, 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 where the query belongs to

Category nameCategory description
Derived tablesQueries of this category provide information about the derived tables (views, materialized views), which are used to implement virtual data layer.
Duplication of implementation elementsQueries of this catergory provide information about the duplication of the database objects.
SecurityQueries of this category provide information about the security measures.
User-defined routinesQueries of this category provide information about the user-defined routines

The list of all the queries