The list of all the queries

Incorrect characterization of a user-defined routine as a "stable" routine

Query goal: Find stable routines that contain INSERT, UPDATE, DELETE, SELECT … FOR UPDATE, or LOCK statement. The DBMS should get a correct background information about the behaviour of a routine. Stable routines cannot modify data in a database, lock tables, or its specific rows.
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.
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: Define the routine as volatile.
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(pg_get_functiondef(pg_proc.oid),'[\r\n]','<br>','g')  AS routine_src
FROM 
  pg_catalog.pg_proc, 
  pg_catalog.pg_namespace
WHERE 
  pg_proc.pronamespace = pg_namespace.oid
AND  provolatile='s'
AND pg_proc.prokind<>'a'
AND pg_get_functiondef(pg_proc.oid)~*'((insert|update|delete|lock)[[: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 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  provolatile='s'
AND pg_proc.prokind<>'a'
AND pg_get_functiondef(pg_proc.oid)~*'((insert|update|delete|lock)[[: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 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
User-defined routinesQueries of this category provide information about the user-defined routines

Reference materials for further reading

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

The list of all the queries