Avoid creating user-defined routines that have the same name as some extension routine because it may cause confusion.
Notes
Refers to the column pg_proc.prokind and thus works starting from PostgreSQL 11. 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.
Type
Problem detection (Each row in the result could represent a flaw in the design)
WITH user_deined_routines AS (SELECT
pg_namespace.nspname AS routine_schema,
pg_proc.proname AS routine_name,
pg_get_function_identity_arguments(pg_proc.oid) AS parameters,
CASE WHEN pg_proc.prokind='f' THEN 'FUNCTION'
WHEN pg_proc.prokind='p' THEN 'PROCEDURE'
WHEN pg_proc.prokind='a' THEN 'AGGREGATE FUNCTION'
WHEN pg_proc.prokind='w' THEN 'WINDOW FUNCTION' END AS routine_type
FROM
pg_catalog.pg_proc,
pg_catalog.pg_namespace
WHERE
pg_proc.pronamespace = pg_namespace.oid
AND pg_proc.proname NOT IN ('f_assume_you_must_use_files', 'f_check_format_comma_separated_list', 'f_check_password', 'f_default_value_with_no_match') AND
pg_namespace.nspname 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
WHERE EXISTS (SELECT 1 FROM pg_catalog.pg_extension e WHERE d.refobjid=e.oid) AND
d.objid=pg_proc.oid)
),
extension_routines AS (SELECT
n.nspname AS extension_routine_schema,
p.proname AS extension_routine_name,
pg_get_function_identity_arguments(p.oid) AS extension_routine_parameters,
e.extname AS extension_name,
e.extversion AS extension_version,
CASE WHEN p.prokind='f' THEN 'FUNCTION'
WHEN p.prokind='p' THEN 'PROCEDURE'
WHEN p.prokind='a' THEN 'AGGREGATE FUNCTION'
WHEN p.prokind='w' THEN 'WINDOW FUNCTION' END AS extension_routine_type
FROM
pg_catalog.pg_proc p,
pg_catalog.pg_namespace n,
pg_catalog.pg_depend d,
pg_catalog.pg_extension e
WHERE
p.pronamespace = n.oid
AND p.oid=d.objid
AND e.oid=d.refobjid)
SELECT routine_schema, routine_name, parameters, routine_type, extension_routine_schema, extension_routine_parameters, extension_routine_type, extension_name, extension_version
FROM user_deined_routines, extension_routines
WHERE routine_name=extension_routine_name
ORDER BY routine_schema, routine_name, parameters;
SQL statements that help generate fixes for the identified problem.
SQL Query to Generate Fix
Description
WITH user_deined_routines AS (SELECT
pg_namespace.nspname AS routine_schema,
pg_proc.proname AS routine_name,
pg_get_function_identity_arguments(pg_proc.oid) AS parameters,
CASE WHEN pg_proc.prokind='f' THEN 'FUNCTION'
WHEN pg_proc.prokind='p' THEN 'PROCEDURE'
WHEN pg_proc.prokind='a' THEN 'AGGREGATE FUNCTION'
WHEN pg_proc.prokind='w' THEN 'WINDOW FUNCTION' END AS routine_type
FROM
pg_catalog.pg_proc,
pg_catalog.pg_namespace
WHERE
pg_proc.pronamespace = pg_namespace.oid
AND pg_proc.proname NOT IN ('f_assume_you_must_use_files', 'f_check_format_comma_separated_list', 'f_check_password', 'f_default_value_with_no_match') AND
pg_namespace.nspname 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
WHERE EXISTS (SELECT 1 FROM pg_catalog.pg_extension e WHERE d.refobjid=e.oid) AND
d.objid=pg_proc.oid)
),
extension_routines AS (SELECT
n.nspname AS extension_routine_schema,
p.proname AS extension_routine_name,
pg_get_function_identity_arguments(p.oid) AS extension_routine_parameters,
e.extname AS extension_name,
e.extversion AS extension_version,
CASE WHEN p.prokind='f' THEN 'FUNCTION'
WHEN p.prokind='p' THEN 'PROCEDURE'
WHEN p.prokind='a' THEN 'AGGREGATE FUNCTION'
WHEN p.prokind='w' THEN 'WINDOW FUNCTION' END AS extension_routine_type
FROM
pg_catalog.pg_proc p,
pg_catalog.pg_namespace n,
pg_catalog.pg_depend d,
pg_catalog.pg_extension e
WHERE
p.pronamespace = n.oid
AND p.oid=d.objid
AND e.oid=d.refobjid),
suspected_routines AS (SELECT routine_schema, routine_name, parameters, routine_type, extension_routine_schema, extension_routine_parameters, extension_routine_type, extension_name, extension_version
FROM user_deined_routines, extension_routines
WHERE routine_name=extension_routine_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:
Name
Description
Find problems automatically
Queries, 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:
Name
Description
Does not work in some earlier PostgreSQL version
Queries of this category provide information that was not available in some earlier PostgreSQL version
Extensions
Queries of this category provide information about extensions in the database.
Overloading
Queries of this category provide information about overloading of routines.