This query audits the metadata of user-defined routines to enforce traceability between the implementation and the design specifications. It identifies routines whose comments lack a standardized reference to the specific database operation contract they implement. The query checks for the absence of a required identifier pattern, typically formatted as OP followed by a number (e.g., OP1, OP12). Enforcing this standard ensures that every routine can be mapped back to its originating requirement or business rule.
Notes
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. 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 searches routines that implement data modifiction operations. However, there could be operations that task is to read data and that are implemented as functions in a database.
Type
Problem detection (Each row in the result could represent a flaw in the design)
SELECT
n.nspname AS routine_schema,
p.proname AS routine_name,
pg_get_function_identity_arguments(p.oid) AS parameters,
CASE WHEN p.prokind='f' THEN 'FUNCTION'
WHEN p.prokind='p' THEN 'PROCEDURE'
WHEN p.prokind='w' THEN 'WINDOW FUNCTION' END AS routine_type,
d.description AS comment,
regexp_replace(pg_get_functiondef(p.oid),'[\r\n]',' ','g') AS routine_src
FROM
(pg_catalog.pg_proc p JOIN pg_catalog.pg_namespace n ON p.pronamespace = n.oid) JOIN pg_catalog.pg_type t ON p.prorettype=t.oid
LEFT JOIN pg_catalog.pg_description d ON p.oid=d.objoid
WHERE
p.prokind<>'a'
AND p.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 n.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 t.typname<>'trigger'
AND (d.description IS NULL OR d.description!~*'([[:space:]]*|")OP([[:space:]]|#)*[[:digit:]]')
AND pg_get_functiondef(p.oid)~*'([[:space:]]|[(])*(INSERT|UPDATE|DELETE)[[:space:]]'
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
Comfortability of database evolution
Queries of this category provide information about the means that influence database evolution.
Comments
Queries of this category provide information about comments to the database objects that have been registered in the system catalog.
User-defined routines
Queries of this category provide information about the user-defined routines