This query identifies user-defined functions that contain restricted Transaction Control Language (TCL) statements, such as BEGIN, COMMIT, ROLLBACK, or SAVEPOINT. In PostgreSQL, functions execute within the context of the calling query's transaction and are strictly prohibited from managing transaction boundaries. Attempting to execute these commands within a function body results in a runtime error. To implement transactional logic (such as committing data in batches), the code must be refactored into a PROCEDURE, which supports transaction management.
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)
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
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),'<','<','g'),'[\r\n]',' ','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)~*'(?