Goal Find parameter names in case of which the same routine has another parameter with the same mode but with more specific name, i.e., the name contains the parameter name in the end or in the beginning.
Notes The query assumes that snake_case is used in the names. The query excludes too generic parameter names "id", "code", and "kood".
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
Data Source INFORMATION_SCHEMA+system catalog
SQL Query
WITH params AS (SELECT 
specific_schema AS routine_schema,
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,
ordinal_position,
data_type,
parameter_mode
FROM 
information_schema.parameters
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 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))
SELECT p.routine_schema, p.routine_name, p.parameters, p.parameter_mode, p.parameter_name AS suspected_name, p.ordinal_position, p.data_type,
string_agg(p2.parameter_name || ' (' || p2.data_type || ')', ',
' ORDER BY p2.ordinal_position) AS more_specific_parameters FROM params AS p INNER JOIN params AS p2 USING (routine_schema, routine_name, parameters) WHERE p.parameter_mode=p2.parameter_mode AND p.parameter_name<>p2.parameter_name AND (p2.parameter_name ILIKE '%\_' || p.parameter_name OR p2.parameter_name ILIKE p.parameter_name || '\_%') AND p.parameter_name NOT IN ('id','code','kood') GROUP BY p.routine_schema, p.routine_name, p.parameters, p.parameter_mode, p.parameter_name, p.ordinal_position, p.data_type ORDER BY p.routine_schema, p.routine_name, p.parameters, p.ordinal_position;
Collections

This query belongs to the following collections:

NameDescription
Find problems about namesA selection of queries that return information about the names of database objects. Contains all the types of queries - problem detection, software measure, and general overview.
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 .
Lexicon bad smells and linguistic antipatternsQueries made to find the occurrences of lexicon bad smells and linguistic antipatterns
Categories

This query is classified under the following categories:

NameDescription
NamingQueries of this category provide information about the style of naming.
User-defined routinesQueries of this category provide information about the user-defined routines

Further reading and related materials:

Reference
Smell "Inconsistent identifier use": Abebe, S.L., Haiduc, S., Tonella, P., Marcus, A., 2011. The effect of lexicon bad smells on concept location in source code. In 2011 IEEE 11th International Working Conference on Source Code Analysis and Manipulation (pp. 125-134). IEEE.