The list of all the queries

Extension routines that execution privilege has been granted to PUBLIC

Query goal: Know the privileges that users have in your system. Probably all the database users do not need these privileges.
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. 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.
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 execution privilege from PUBLIC.
Data source: INFORMATION_SCHEMA+system catalog
SQL query: Click on query to copy it

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,
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.privilege_type='EXECUTE')
SELECT routine_type, routine_schema, routine_name,parameters
FROM public_routines
WHERE 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 for generating SQL statements that help us to fix the problem

SQL queryDescription
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,
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.privilege_type='EXECUTE'),
schemas_with_public_extension_routines AS (SELECT DISTINCT routine_schema
FROM public_routines
WHERE 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))
SELECT format('REVOKE EXECUTE ON ALL FUNCTIONS IN SCHEMA %1$I FROM PUBLIC;', routine_schema) AS statements
FROM schemas_with_public_extension_routines
ORDER BY routine_schema;
Revoke the execution privilege from all the routines in a schema that contains at least one extension routine.

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
ExtensionsQueries of this category provide information about extensions in the database.
SecurityQueries of this category provide information about the security measures.

The list of all the queries