Goal Find immutable routines that contain SELECT statements from a database (including SELECT .. FOR UPDATE), INSERT, UPDATE, DELETE, or LOCK statement. The DBMS should get a correct background information about the behaviour of a routine. Immutable routines should not have side effects and should also not ask data from a database because it could change over time. Immutable routines cannot lock tables or its specific rows.
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.
Type Problem detection (Each row in the result could represent a flaw in the design)
Reliability High (Few or no false-positive results)
License MIT License
Fixing Suggestion Define the routine as volatile.
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(pg_get_functiondef(pg_proc.oid),'[\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.prokind<>'a' AND provolatile='i' AND pg_get_functiondef(pg_proc.oid)~*'((insert|update|delete|lock)[[:space:]]|select[[:space:]].*from[[:space:]].*where[[:space:]]|select[[:space:]].*for[[:space:]]+update)' 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) ORDER BY routine_schema, routine_name, parameters;

SQL statements that help generate fixes for the identified problem.

SQL Query to Generate FixDescription
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 provolatile='i'
AND pg_get_functiondef(pg_proc.oid)~*'((insert|update|delete|lock)[[:space:]]|select[[:space:]].*from[[:space:]].*where[[:space:]]|select[[:space:]].*for[[:space:]]+update)'
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))
SELECT format('ALTER FUNCTION %1$I.%2$I(%3$s) VOLATILE;', routine_schema, routine_name, parameters) AS statements
FROM suspected_routine
ORDER BY routine_schema, routine_name, parameters;
Define the routine as volatile.
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
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

Further reading and related materials:

Reference
The corresponding code smell in case of cleaning code is "G26: Be Precise". (Robert C. Martin, Clean Code)