Goal If the name of a routine parameter and the name of a column of a table that is used in the routine are the same, then it makes it more difficult to understand the code.
Notes In case of table functions the output parameters are not considered because in case of table functions column names correspond to output parameters. The query uses the information_schema view routine_column_usage that was added to PostgreSQL 14. The view contains only information about routines that are written in SQL language and have the SQL-standard body. 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. Here is an example of a routine with such a problem:

CREATE OR REPLACE FUNCTION public.f_delete_emp(empno IN Emp.empno%TYPE)
RETURNS VOID
LANGUAGE SQL
BEGIN ATOMIC
DELETE FROM Emp WHERE empno=empno;
END;

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
Data Source INFORMATION_SCHEMA+system catalog
SQL Query
WITH params AS (SELECT specific_schema, specific_name,
regexp_replace(specific_name,'_[0-9]*$','') AS routine_name, 
pg_get_function_identity_arguments(translate(substring(specific_name,'_[0-9]+$'),'_','')::int::oid) AS parameters,
parameter_name
FROM INFORMATION_SCHEMA.parameters
WHERE  regexp_replace(specific_name,'_[0-9]*$','') NOT IN ('f_assume_you_must_use_files', 'f_check_format_comma_separated_list', 'f_check_password', 'f_default_value_with_no_match') 
AND 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 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 = parameters.specific_name)
AND (NOT (parameter_mode='OUT') OR
NOT EXISTS (SELECT 1
FROM pg_proc pc
WHERE proname || '_' || pc.oid = parameters.specific_name
AND pc.proretset='t')))
SELECT params.specific_schema AS routine_schema, 
params.routine_name,
params.parameters,
params.parameter_name,
rcu.table_schema, 
rcu.table_name, 
rcu.column_name
FROM params INNER JOIN INFORMATION_SCHEMA.routine_column_usage AS rcu USING (specific_schema, specific_name)
WHERE params.parameter_name=rcu.column_name
AND table_schema NOT IN (SELECT schema_name
FROM INFORMATION_SCHEMA.schemata
WHERE schema_name<>'public' AND
schema_owner='postgres' AND schema_name IS NOT NULL) 
ORDER BY params.specific_schema, params.routine_name, params.parameters, column_name;

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.
Does not work in some earlier PostgreSQL versionQueries of this category provide information that was not available in some earlier PostgreSQL version
NamingQueries of this category provide information about the style of naming.
User-defined routinesQueries of this category provide information about the user-defined routines