The list of all the queries

Perhaps a routine does not have a real task

Query goal: Find the routines where the only action is to return an argument value, a constant value, NULL or return the value of OLD or NEW variable in case of trigger functions.
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. 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 return data about trigger functions that RETURN OLD by assuming that perhaps the trigger function was used to cancel changes that have been made by a data manipulation statement. The query also considers routines with SQL-standard bodies, which are permitted starting from PostgreSQL 14. In case of using it prior PostgreSQL 14, one should replace the expression "CASE WHEN pg_proc.prosqlbody IS NULL THEN pg_proc.prosrc ELSE pg_get_function_sqlbody(pg_proc.oid) END" with "pg_proc.prosrc".
Query type: Problem detection (Each row in the result could represent a flaw in the design)
Query reliability: High (Few or no false-positive results)
Query license: MIT License
Fixing suggestion: Add actions to the routine body or drop the routine.
Data source: INFORMATION_SCHEMA+system catalog
SQL query: Click on query to copy it

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((CASE WHEN pg_proc.prosqlbody IS NULL THEN pg_proc.prosrc ELSE pg_get_function_sqlbody(pg_proc.oid) END),'<','&lt','g'),'[\r\n]','<br>','g')  AS routine_body
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_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 ((CASE WHEN pg_proc.prosqlbody IS NULL THEN pg_proc.prosrc ELSE pg_get_function_sqlbody(pg_proc.oid) END)~*'^[[:space:]]*BEGIN[[:space:]]+(ATOMIC){0,1}[[:space:]]*(RETURN|SELECT)[[:space:]]+(["]|['']){0,1}[[:alnum:]]+(["]|['']){0,1};[[:space:]]+END[;]{0,1}[[:space:]]*$' 
OR ((CASE WHEN pg_proc.prosqlbody IS NULL THEN pg_proc.prosrc ELSE pg_get_function_sqlbody(pg_proc.oid) END)~*'^[[:space:]]*(SELECT|RETURN)[[:space:]]+['']{0,1}[[:alnum:]]+['']{0,1};[[:space:]]*$'))
ORDER BY routine_schema, routine_name, parameters;

SQL statements for generating SQL statements that help us to fix the problem

SQL queryDescription
WITH suspected_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
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_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 ((CASE WHEN pg_proc.prosqlbody IS NULL THEN pg_proc.prosrc ELSE pg_get_function_sqlbody(pg_proc.oid) END)~*'^[[:space:]]*BEGIN[[:space:]]+(ATOMIC){0,1}[[:space:]]*(RETURN|SELECT)[[:space:]]+(["]|['']){0,1}[[:alnum:]]+(["]|['']){0,1};[[:space:]]+END[;]{0,1}[[:space:]]*$' 
OR ((CASE WHEN pg_proc.prosqlbody IS NULL THEN pg_proc.prosrc ELSE pg_get_function_sqlbody(pg_proc.oid) END)~*'^[[:space:]]*(SELECT|RETURN)[[:space:]]+['']{0,1}[[:alnum:]]+['']{0,1};[[:space:]]*$')))
SELECT format('DROP ROUTINE %1$I.%2$I(%3$s);', routine_schema, routine_name, parameters) AS statements
FROM suspected_routine
ORDER BY routine_schema, routine_name, parameters;
Drop the routine.

Collections where the query belongs to

Collection nameCollection description
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 where the query belongs to

Category nameCategory description
Does not work in some earlier PostgreSQL versionQueries of this category provide information that was not available in some earlier PostgreSQL version
StubsQueries of this catergory provide information about stubs (piece of code used to stand in for some other programming functionality).
User-defined routinesQueries of this category provide information about the user-defined routines

The list of all the queries