The list of all the queries

Grantable routine privileges

Query goal: Find routine 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: 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. 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 rp.grantee, rp.specific_schema AS routine_schema, rp.routine_name, 
pg_get_function_identity_arguments(translate(substring(rp.specific_name,'_[0-9]+$'),'_','')::int::oid) AS parameters,
rp.privilege_type
FROM information_schema.routine_privileges AS rp INNER JOIN information_schema.routines AS t
USING (specific_schema, specific_name)
WHERE rp.is_grantable='YES' AND rp.specific_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 rp.grantee=r.rolname)
ORDER BY specific_schema, specific_name;

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

SQL queryDescription
WITH grantable_privileges AS (
SELECT rp.grantee, rp.specific_schema AS routine_schema, rp.routine_name, 
pg_get_function_identity_arguments(translate(substring(rp.specific_name,'_[0-9]+$'),'_','')::int::oid) AS parameters,
rp.privilege_type
FROM information_schema.routine_privileges AS rp INNER JOIN information_schema.routines AS t
USING (specific_schema, specific_name)
WHERE rp.is_grantable='YES' AND rp.specific_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 rp.grantee=r.rolname))
SELECT format('REVOKE GRANT OPTION FOR ALL PRIVILEGES ON ROUTINE %1$I.%2$I(%3$s) FROM %4$I;', routine_schema, routine_name, parameters, grantee) AS statements
FROM grantable_privileges
ORDER BY routine_schema, routine_name;
Revoke WITH GRANT OPTION privilege.

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
SecurityQueries of this category provide information about the security measures.
User-defined routinesQueries of this category provide information about the user-defined routines

Reference materials for further reading

Reference
https://en.wikipedia.org/wiki/Principle_of_least_privilege
https://www.postgresql.org/docs/current/ddl-priv.html

The list of all the queries