Query goal: | Do not write incorrect code. Variable NEW: "Data type RECORD; variable holding the new database row for INSERT/UPDATE operations in row-level triggers. This variable is null in statement-level triggers and for DELETE operations." (PostgreSQL documentation) |
Notes about the query: | The Tr subquery has been created based on the subquery of INFORMATION_SCHEMA.triggers view. 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. The query excludes trigger functions that use Coalesce function, e.g., Coalesce(NEW, OLD). The query also excludes trigger functions that refer to OLD variable, and TG_OP variable, and INSERT or UPDATE operation. The reasoning is that it is possible to write a trigger function that implements a reaction to different events. |
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: | Such trigger procedure can use the variable OLD. |
Data source: | INFORMATION_SCHEMA+system catalog |
SQL query: | Click on query to copy it
WITH Tr AS (SELECT n.nspname AS trigger_schema, t.tgname AS trigger_name, em.text AS event_manipulation, c.relname AS trigger_table, np.nspname AS routine_schema, p.proname AS routine_name, p.prosrc AS routine_definition, (SELECT DISTINCT action_condition FROM INFORMATION_SCHEMA.triggers AS it WHERE it.trigger_schema=n.nspname AND it.event_object_table=c.relname AND it.trigger_name=t.tgname) AS action_condition, CASE t.tgtype::integer & 1 WHEN 1 THEN 'ROW' ELSE 'STATEMENT' END AS action_orientation, CASE t.tgtype::integer & 66 WHEN 2 THEN 'BEFORE' WHEN 64 THEN 'INSTEAD OF' ELSE 'AFTER' END AS action_timing FROM pg_namespace n, pg_class c, pg_trigger t, pg_proc p, pg_namespace np, ( VALUES (4,'INSERT'), (8,'DELETE'), (16,'UPDATE'), (32,'TRUNCATE')) em(num, text) WHERE n.oid = c.relnamespace AND c.oid = t.tgrelid AND t.tgfoid=p.oid AND p.pronamespace=np.oid AND (t.tgtype::integer & em.num) <> 0 AND NOT t.tgisinternal AND NOT pg_is_other_temp_schema(n.oid)) SELECT trigger_schema, trigger_table, action_timing, event_manipulation, action_orientation, action_condition, routine_name, regexp_replace(routine_definition,'[\r\n]','<br>','g') AS routine_definition FROM Tr WHERE action_timing IN ('BEFORE', 'INSTEAD OF') AND action_orientation='ROW' AND event_manipulation='DELETE' AND routine_definition~* '(([[:space:]]|=|<>|!=|~|~[*]|<|>|<=|>=)(?<!Coalesce[[:space:]]*[(].*)NEW([.]|;|[[:space:]])|RETURN[[:space:]].*(?<!Coalesce[[:space:]]*[(].*)NEW)' AND routine_definition!~* 'OLD' AND routine_definition!~* 'TG_OP' AND routine_definition!~* '(''INSERT''|''UPDATE'')' ORDER BY trigger_schema, trigger_table, routine_name; |
Collection name | Collection description |
---|---|
Find problems automatically | Queries, 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 . |
Category name | Category description |
---|---|
Triggers and rules | Queries of this category provide information about triggers and rules in a database. |
Reference |
---|
https://www.postgresql.org/docs/current/plpgsql-trigger.html |