Find user-defined routines that contain an invocation of a system-defined function without providing any argument. The query considers all aggregate functions as well as some popular scalar functions.
Notes
Refers to the column pg_proc.prokind and thus works starting from PostgreSQL 11. 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 the routines that are a part of an extension. 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 can return false positive results if incorrect invocations are in comments. The query tries to avoid false positive results if apparent invocation is a part of the name of the routine.
Type
Problem detection (Each row in the result could represent a flaw in the design)
Add the necessary arguments to the invocation of the function.
Data Source
INFORMATION_SCHEMA+system catalog
SQL Query
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='w' THEN 'WINDOW FUNCTION' END AS routine_type,
regexp_replace( regexp_replace(pg_get_functiondef(pg_proc.oid),'<','<','g'),'[\r\n]',' ','g') AS routine_src
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.prokind<>'a'
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 pg_get_functiondef(pg_proc.oid)~*'[^_](array_agg|avg|bit_and|bit_or|bool_and|bool_or|count|every|json_agg|jsonb_agg|json_object_agg|jsonb_object_agg|max|min|string_agg|sum|xmlagg|upper|lower|trim|coalesce|format)(?![^;]+language[[:space:]])[[:space:]]*[(][[:space:]]*[)]'
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)
ORDER BY routine_schema, routine_name, parameters;
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
Does not work in some earlier PostgreSQL version
Queries of this category provide information that was not available in some earlier PostgreSQL version
Stubs
Queries of this catergory provide information about stubs (piece of code used to stand in for some other programming functionality).
Syntactics
Queries of this category provide information about syntactic mistakes.
System-defined functions
Queries of this category provide information about the use of system-defined functions.
User-defined routines
Queries of this category provide information about the user-defined routines
Further reading and related materials:
Reference
Rule 6 in: Delplanque, J., Etien, A., Auverlot, O., Mens, T., Anquetil, N., Ducasse, S.: CodeCritics applied to database schema: Challenges and first results. In: 2017 IEEE 24th International Conference on Software Analysis, Evolution and Reengineering (SANER), pp. 432-436. IEEE, (2017).