Find unnamed parameters in PL/PGSQL routines that do not declare aliases for parameters and in SQL routines. Avoid unnamed parameters because dependency on position in case of referencing the parameters makes evolving the code more difficult. In case of unnamed parameters - if one changes the order of parameters in the routine signature, then one has to change the body of the routine in order to use correct references. The bigger is the number of parameters in a routine the more the unnamed parameters make it more difficult to understand the routine.
Notes
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. In the output data the query removes from the end of the routine name the numbers, which represent the object identifier of the routine in the system catalog. The query does not consider the routines that are a part of an extension.
Type
Problem detection (Each row in the result could represent a flaw in the design)
Give a name to each parameter and refer to parameters by name not by their position in the list of parameters.
Data Source
INFORMATION_SCHEMA+system catalog
SQL Query
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,
ordinal_position,
parameters.data_type,
parameter_mode,
(length(pg_get_function_identity_arguments(translate(substring(specific_name,'_[0-9]+$'),'_','')::int::oid))-
length(translate(pg_get_function_identity_arguments(translate(substring(specific_name,'_[0-9]+$'),'_','')::int::oid),',','')))+1 AS total_nr_of_parameters_in_routine
FROM
information_schema.parameters INNER JOIN information_schema.routines USING (specific_schema, specific_name)
WHERE
(external_language='SQL'
OR (
external_language='PLPGSQL'
AND pg_get_functiondef(translate(substring(specific_name,'_[0-9]+$'),'_','')::int::oid)!~*'[[:space:]]alias[[:space:]]+for'
))
AND parameter_name IS NULL
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)
ORDER BY total_nr_of_parameters_in_routine DESC, routine_schema, routine_name, parameters, ordinal_position;
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
Comfortability of database evolution
Queries of this category provide information about the means that influence database evolution.
Naming
Queries of this category provide information about the style of naming.
User-defined routines
Queries of this category provide information about the user-defined routines