Goal You should follow the principle of least privilege and thus not have in your database user-defined routines that execution privilege is granted to PUBLIC, i.e., to all the database users now and in the future. By default, PostgreSQL gives routine execution privileges to PUBLIC.
Notes The query uses specific name of each routine to find out its oid. It uses the oid-s to make sure that the routine does not belong to 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. In the output data the query removes from the end of the routine name the numbers, which represent the object identifier of the routine in the system catalog.
Type Problem detection (Each row in the result could represent a flaw in the design)
Reliability High (Few or no false-positive results)
License MIT License
Fixing Suggestion Revoke the routine execution privilege from PUBLIC.
Data Source INFORMATION_SCHEMA+system catalog
SQL Query
WITH public_routines AS (SELECT DISTINCT rp.routine_schema, rp.routine_name, r.routine_type, pg_get_function_identity_arguments(translate(substring(rp.specific_name,'_[0-9]+$'),'_','')::int::oid) AS parameters,
translate(substring(rp.specific_name,'_[0-9]+$'),'_','')::int::oid AS routine_oid
FROM information_schema.routine_privileges AS rp INNER JOIN information_schema.routines AS r USING (routine_schema, specific_name)
WHERE rp.grantee='PUBLIC' AND 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 rp.privilege_type='EXECUTE')
SELECT routine_type, routine_schema, routine_name,parameters
FROM public_routines
WHERE NOT EXISTS (SELECT 1
FROM pg_catalog.pg_depend d 
WHERE EXISTS (SELECT 1 FROM pg_catalog.pg_extension e WHERE d.refobjid=e.oid) AND
d.objid=public_routines.routine_oid)
ORDER BY routine_schema, routine_name, parameters;

SQL statements that help generate fixes for the identified problem.

SQL Query to Generate FixDescription
WITH public_routines AS (SELECT DISTINCT rp.routine_schema, rp.routine_name, r.routine_type, pg_get_function_identity_arguments(translate(substring(rp.specific_name,'_[0-9]+$'),'_','')::int::oid) AS parameters,
translate(substring(rp.specific_name,'_[0-9]+$'),'_','')::int::oid AS routine_oid, rp.privilege_type
FROM information_schema.routine_privileges AS rp,
information_schema.routines AS r
WHERE rp.grantee='PUBLIC' AND 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
rp.routine_schema=r.routine_schema AND 
rp.specific_name=r.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'))
SELECT format('REVOKE %1$s ON ROUTINE %2$I.%3$I(%4$s) FROM PUBLIC;', privilege_type, routine_schema, routine_name, parameters) AS statements
FROM public_routines
WHERE NOT EXISTS (SELECT 1
FROM pg_catalog.pg_depend d 
WHERE EXISTS (SELECT 1 FROM pg_catalog.pg_extension e WHERE d.refobjid=e.oid) AND
d.objid=public_routines.routine_oid)
ORDER BY routine_schema, routine_name, parameters, privilege_type;
Revoke the routine execution privilege from PUBLIC.
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