The list of all the queries

Functions that have transactional control

Query goal: Find functions that contain transactional control statements (BEGIN, START TRANSACTION, COMMIT, ROLLBACK, SAVEPOINT) in their body. PostgreSQL does not permit transaction control in 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.
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: If you want to use transactional control in routines, then you must use procedures. If one does not want to change the name and parameters of the function, then one can execute CREATE OR REPLACE FUNCTION … statement where transactional control statements have been removed from the function body.
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( regexp_replace(pg_get_functiondef(pg_proc.oid),'<','&lt','g'),'[\r\n]','<br>','g')  AS func_src
FROM  
  pg_catalog.pg_proc, 
  pg_catalog.pg_namespace
WHERE 
  pg_proc.pronamespace = pg_namespace.oid 
  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_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 pg_get_functiondef(pg_proc.oid)~*'(BEGIN[[:space:]]*;|START[[:space:]]TRANSACTION|COMMIT|ROLLBACK|SAVEPOINT)' 
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
Fatal problemsQueries of this category provide information about problems that render a part of a database unusable.
TransactionsQueries of this catergory provide information about the use of transactions.
User-defined routinesQueries of this category provide information about the user-defined routines

The list of all the queries