Goal Avoid creating user-defined routines that have the same name as some system-defined routine because it may cause confusion.
Notes 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 does not consider routines that are a part of an extension.
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 Rename or drop the user-defined routine.
Data Source INFORMATION_SCHEMA+system catalog
SQL Query
WITH routines_pg_catalog AS (SELECT routine_name
FROM information_schema.routines
WHERE specific_schema ='pg_catalog')
SELECT specific_schema AS routine_schema, routine_name, pg_get_function_identity_arguments(translate(substring(specific_name,'_[0-9]+$'),'_','')::int::oid) AS parameters, routine_type
FROM information_schema.routines
WHERE specific_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 routine_name IN (SELECT routine_name FROM routines_pg_catalog)
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 = routines.specific_name)
ORDER BY specific_schema, routine_name, parameters;

SQL statements that help generate fixes for the identified problem.

SQL Query to Generate FixDescription
WITH routines_pg_catalog AS (SELECT routine_name
FROM information_schema.routines
WHERE specific_schema ='pg_catalog'),
suspected_routines AS (SELECT specific_schema AS routine_schema, routine_name, pg_get_function_identity_arguments(translate(substring(specific_name,'_[0-9]+$'),'_','')::int::oid) AS parameters,
routine_type
FROM information_schema.routines
WHERE specific_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 routine_name IN (SELECT routine_name FROM routines_pg_catalog)
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 = routines.specific_name))
SELECT format('DROP %1$s %2$I.%3$I(%4$s);', routine_type, routine_schema, routine_name, parameters) AS statements
FROM suspected_routines
ORDER BY routine_schema, routine_name, parameters;
Drop the routine.
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
OverloadingQueries of this category provide information about overloading of routines.
SecurityQueries of this category provide information about the security measures.
System-defined functionsQueries of this category provide information about the use of system-defined functions.
User-defined routinesQueries of this category provide information about the user-defined routines