Query goal: | Find named input parameters that are not referenced in the routine body. All the parameters that are presented in the routine signature declaration must be used in its body. Otherwise these are dead code elements. |
Notes about the query: | 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. |
Query type: | Problem detection (Each row in the result could represent a flaw in the design) |
Query reliability: | Medium (Medium number of false-positive results) |
Query license: | MIT License |
Fixing suggestion: | Refer the parameter in the body or remove it from the routine signature. In case of the former, one has to use use CREATE OR REPLACE statement. In case of the latter, one has to drop the routine and create it with a new set of parameters. |
Data source: | INFORMATION_SCHEMA+system catalog |
SQL query: | Click on query to copy it
WITH routine AS (SELECT pg_namespace.nspname AS routine_schema, pg_proc.proname AS routine_name, pg_proc.proname || '_' || pg_proc.oid AS routine_specific_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='w' THEN 'WINDOW FUNCTION' END AS routine_type, regexp_replace((CASE WHEN pg_proc.prosqlbody IS NULL THEN pg_proc.prosrc ELSE pg_get_function_sqlbody(pg_proc.oid) END),'[\r\n]','<br>','g') AS routine_body, 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.prokind<>'a' 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)) SELECT routine_schema, routine_name, parameters, routine_type, routine_body, routine_param AS unused_parameter FROM routine AS r WHERE EXISTS (SELECT * FROM INFORMATION_SCHEMA.parameters AS p WHERE r.routine_schema=p.specific_schema AND r.routine_specific_name=p.specific_name AND r.routine_param=p.parameter_name AND p.parameter_mode='IN') AND routine_body NOT ILIKE '%'|| routine_param || '%' ORDER BY routine_schema, routine_name, parameters, unused_parameter; |
Collection name | Collection 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 . |
Category name | Category description |
---|---|
Comfortability of database evolution | Queries of this category provide information about the means that influence database evolution. |
Does not work in some earlier PostgreSQL version | Queries of this category provide information that was not available in some earlier PostgreSQL version |
Unused implementation elements | Queries of this catergory provide information about the database objects that are not used. |
User-defined routines | Queries of this category provide information about the user-defined routines |
Reference |
---|
https://en.wikipedia.org/wiki/Dead_code |
The corresponding code smells in case of cleaning code are "F4: Dead Function" and "G9: Dead Code". (Robert C. Martin, Clean Code) |