Goal A large routine may have multiple tasks that should be split between multiple routines, each of which has a more focused task. Find the PL/pgSQL routines where the number of physical lines of code is bigger than 40.
Notes Query counts the number of newline characters in the routine to find the number of physical lines. To do so it finds the routine body length in case of newlines have been removed and subtracts it from the length of the initial routine body. Query refers to the column pg_proc.prokind and thus works starting from PostgreSQL 11. 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. 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.
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
Fixing Suggestion Create multiple routines, each smaller and with a more specific task, instead one big routine. Consider using SQL instead of PL/pgSQL as the routine language. Many tasks one can solve with SQL statements (in the declarative manner) and with smaller amount of code compared to the procedural code in a PL/pgSQL routine.
Data Source INFORMATION_SCHEMA+system catalog
SQL Query
WITH pl_pgsql_routine AS (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='a' THEN 'AGGREGATE FUNCTION'
  WHEN pg_proc.prokind='w' THEN 'WINDOW FUNCTION' END AS routine_type,
  regexp_replace(pg_proc.prosrc,'[\r\n]','
','g') AS routine_src, length(pg_proc.prosrc)-length(replace(pg_proc.prosrc,E'\n',''))-1 AS physical_lines_of_code FROM pg_catalog.pg_proc, pg_catalog.pg_namespace, pg_catalog.pg_language WHERE pg_proc.pronamespace = pg_namespace.oid AND pg_proc.prolang = pg_language.oid AND pg_language.lanname='plpgsql' 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_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_src, physical_lines_of_code FROM pl_pgsql_routine WHERE physical_lines_of_code>40 ORDER BY physical_lines_of_code DESC, routine_schema, routine_name, parameters;
Collections

This query belongs to the following collections:

NameDescription
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 .
Categories

This query is classified under the following categories:

NameDescription
Comfortability of database evolutionQueries of this category provide information about the means that influence database evolution.
Does not work in some earlier PostgreSQL versionQueries of this category provide information that was not available in some earlier PostgreSQL version
User-defined routinesQueries of this category provide information about the user-defined routines