Goal You must give rights to use routines to the users/roles that correspond to applications.
Notes The query returns a row if there are no user-defined routines that execution privilege is granted to some non-superuser. The query does not consider the routines that are a part of an extension. It could be that the user, which corresponds to an application, has some but not all the necessary privileges in the database. In this case the query will give false negative answer. The condition in the query ensures that if the requirement is not fulfilled, then the query returns one row, otherwise it does not return a row. The result is achieved by using a PostgreSQL feature that permits SELECT statements without the FROM clause.
Type Problem detection (Each row in the result could represent a flaw in the design)
Reliability Medium (Medium number of false-positive results)
License MIT License
Data Source INFORMATION_SCHEMA+system catalog
SQL Query
WITH privs AS (SELECT DISTINCT rp.routine_schema, rp.routine_name, pg_get_function_identity_arguments(translate(substring(rp.specific_name,'_[0-9]+$'),'_','')::int::oid) AS parameters, rp.grantee, rp.privilege_type, rp.is_grantable
FROM information_schema.routine_privileges AS rp
WHERE rp.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
NOT EXISTS (SELECT 1
FROM pg_catalog.pg_depend d inner join pg_catalog.pg_proc pc ON d.objid=pc.oid
WHERE EXISTS (SELECT 1 FROM pg_catalog.pg_extension e WHERE d.refobjid=e.oid) AND
pc.proname || '_' || pc.oid = rp.specific_name) AND
rp.routine_name NOT IN ('f_assume_you_must_use_files', 'f_check_format_comma_separated_list', 'f_check_password', 'f_default_value_with_no_match') AND
grantee<>'PUBLIC' AND
NOT EXISTS (SELECT 1
FROM pg_catalog.pg_roles r
WHERE rolsuper=TRUE AND rp.grantee=r.rolname))
SELECT 'You must give rights to use routines to the users/roles that correspond to applications' AS comment
WHERE (SELECT Count(*) AS cnt FROM privs)=0;

Collections

This query belongs to the following collections:

NameDescription
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

This query is classified under the following categories:

NameDescription
SecurityQueries of this category provide information about the security measures.
User-defined routinesQueries of this category provide information about the user-defined routines

Further reading and related materials:

Reference
https://www.postgresql.org/docs/current/ddl-priv.html