The list of all the queries

PL/pgSQL functions without the RETURN clause

Query goal: The return value of a function cannot be left undefined. If control reaches the end of the top-level block of the function without hitting a RETURN statement, a run-time error will occur. This restriction does not apply to functions with output parameters and functions returning void, however. In those cases a RETURN statement is automatically executed if the top-level block finishes. It also does not apply to trigger functions that only task is to raise an exception.
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. (length(pg_proc.prosrc)-length(replace(pg_proc.prosrc,E';','')))>2 ensures that the routine has at least two logical lines of code.
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
Data source: INFORMATION_SCHEMA+system catalog
SQL query: Click on query to copy it

SELECT 
  pg_namespace.nspname AS func_schema, 
  pg_proc.proname AS func_name, 
   pg_get_function_identity_arguments(pg_proc.oid) AS parameters,
  regexp_replace(pg_proc.prosrc,'[\r\n]','<br>','g')  AS func_src,
  pg_type.typname AS return_type
FROM 
  pg_catalog.pg_proc, 
  pg_catalog.pg_namespace,
  pg_catalog.pg_language,
  pg_catalog.pg_type
WHERE 
  pg_proc.pronamespace = pg_namespace.oid AND
  pg_proc.prolang = pg_language.oid AND
  pg_proc.prorettype = pg_type.oid AND
  pg_language.lanname='plpgsql' AND
  pg_proc.prokind='f' 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_type.typname<>'void' AND
 (pg_proc.proargmodes IS NULL AND array_position(pg_proc.proargmodes, 'o', 1) IS NULL) AND
 prosrc!~*'[[:space:]]RETURN[[:space:]]' 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
(length(pg_proc.prosrc)-length(replace(pg_proc.prosrc,E';','')))>2 AND
prosrc!~*'[[:space:]]RAISE[[:space:]]+EXCEPTION[[:space:]]'
ORDER BY func_schema, func_name, parameters;

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
Triggers and rulesQueries of this category provide information about triggers and rules in a database.
User-defined routinesQueries of this category provide information about the user-defined routines

The list of all the queries