Goal Write code that is easy to understand and not unnecessarily long. A routine cannot have two or more parameters with the same name. In this case using longer identifier in the form routine_name.parameter name is unnecessary.
Notes Refers to the column pg_proc.prokind and thus works starting from PostgreSQL 11. 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. The query does not consider the routines that are a part of 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. The query does not consider routines with SQL-standard bodies, which are permitted starting from PostgreSQL 14. The reason is that these are parsed at creation time and in the reproduced source of the routine the parameters actually are sometimes preceded with the routine name.
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 In the routine body, instead of using an identifier with the form routine_name.parameter_name use identifier with the form parameter_name.
Data Source INFORMATION_SCHEMA+system catalog
SQL Query
WITH routine 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,
   regexp_replace(pg_proc.prosrc,'[\r\n]','
','g') AS routine_src, unnest(pg_proc.proargnames) AS routine_param 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_proc.proargnames IS NOT NULL 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) AND pg_proc.prosrc<>'') SELECT routine_schema, routine_name, parameters, routine_type, regexp_replace(routine_src, routine_name,'' || routine_name || '','g') AS routine_src, routine_param AS suspected_parameter FROM routine WHERE routine_src ILIKE '%'|| routine_name || '.' || routine_param || '%' ORDER BY routine_schema, routine_name, parameters, suspected_parameter;
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
Does not work in some earlier PostgreSQL versionQueries of this category provide information that was not available in some earlier PostgreSQL version
User-defined routinesQueries of this category provide information about the user-defined routines