Goal Find user-defined routines with the exact duplicate body and parameters. There should not be multiple routines with exactly the same body and parameters (name, type). Having such duplicates is redundancy. Do remember that the same task can usually be solved in multiple different ways. Thus, the exact copies of routine bodies are not the only possible duplication. Moreover, it could be that different routines that solve the same task have different parameter names (but the parameters have the same types, ordinal positions, default values or the routines have different order of parameters). Thus, the query does not find all the duplications.
Notes The query does not consider the routines that are a part of an extension. In the returned body of routine the query replaces each newline character with the line break (br) tag for the better readability in case the query result is displayed in a web browser. In case of the string_agg function, the line break (br) tag is used as a part of the separator for the better readability in case the query result is displayed in a web browser. 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 also considers routines with SQL-standard bodies, which are permitted starting from PostgreSQL 14. In case of using it prior PostgreSQL 14, one should replace the expression "CASE WHEN pg_proc.prosqlbody IS NULL THEN pg_proc.prosrc ELSE pg_get_function_sqlbody(pg_proc.oid) END" with "pg_proc.prosrc".
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
Fixing Suggestion All but one are redundant. Drop the redundant routines.
Data Source INFORMATION_SCHEMA+system catalog
SQL Query
SELECT regexp_replace(CASE WHEN pg_proc.prosqlbody IS NULL THEN pg_proc.prosrc ELSE pg_get_function_sqlbody(pg_proc.oid) END,'[\r\n]','
','g') AS routine_body, pg_get_function_identity_arguments(pg_proc.oid) AS parameters, string_agg(pg_namespace.nspname || '.'|| pg_proc.proname,';
' ORDER BY pg_namespace.nspname || '.'|| pg_proc.proname) AS routines, Count(*) AS number_of_routines 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) GROUP BY routine_body, parameters HAVING Count(*)>1 ORDER BY Count(*) DESC, parameters;

SQL statements that help generate fixes for the identified problem.

SQL Query to Generate FixDescription
WITH duplicate_routines AS (SELECT regexp_replace(CASE WHEN pg_proc.prosqlbody IS NULL THEN pg_proc.prosrc ELSE pg_get_function_sqlbody(pg_proc.oid) END,'[\r\n]','
','g') AS routine_body, pg_get_function_identity_arguments(pg_proc.oid) AS parameters, array_agg(pg_namespace.nspname || '.' || pg_proc.proname) AS routine_array 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) GROUP BY routine_body, parameters HAVING Count(*)>1) SELECT format('DROP ROUTINE %1$s(%2$s);', unnest(routine_array), parameters) AS statements FROM Duplicate_routines ORDER BY routine_body, parameters;
Drop the routine. One of the routines must stay in place.
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
Comfortability of database evolutionQueries of this category provide information about the means that influence database evolution.
Duplication of implementation elementsQueries of this catergory provide information about the duplication of the database objects.
User-defined routinesQueries of this category provide information about the user-defined routines

Further reading and related materials:

Reference
https://refactoring.guru/smells/alternative-classes-with-different-interfaces
https://refactoring.guru/smells/duplicate-code
The corresponding code smell in case of cleaning code is "G5: Duplication". (Robert C. Martin, Clean Code)