Query goal: | Find trigger functions that contain a conditional (IF or CASE) but do not contain a SELECT statement before these. The latter condition is for the reason that one cannot use a subquery in the WHEN clause. Thus, if one wants to make a query and decide the further action based on the results of the query, then one must do it within the body of the function. |
Notes about the query: | 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. Trigger WHEN clause cannot contain a subquery. The query assumes that if a trigger function contains a SELECT statement, then its result is used in the condition, i.e., such function cannot be simplified. 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. The query excludes triggers that refer to special variables that name starts with "TG_" (e.g., TG_NAME). |
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 |
Fixing suggestion: | If possible put the condition to the WHEN clause of the trigger in order to simplify the trigger function and reduce possibility that the function is executed unnecessarily. |
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
FROM
pg_catalog.pg_proc,
pg_catalog.pg_namespace,
pg_catalog.pg_type
WHERE pg_proc.pronamespace = pg_namespace.oid AND pg_type.oid=pg_proc.prorettype
AND pg_type.typname='trigger'
AND prosrc~*'(END[[:space:]]+CASE|END[[:space:]]+IF)'
AND prosrc!~*'SELECT[[:space:]].*(END[[:space:]]+CASE|END[[:space:]]+IF)'
AND prosrc!~*'TG_(NAME|WHEN|LEVEL|OP|RELID|RELNAME|TABLE_NAME|TABLE_SCHEMA|NARGS|ARGV\[[[:digit:]]+\])[[: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)
ORDER BY func_schema, func_name, parameters; |