Goal This query identifies row-level BEFORE and INSTEAD OF triggers that explicitly RETURN NULL. In PostgreSQL's trigger execution model, this return value acts as a cancellation signal. For BEFORE triggers on tables, it aborts the operation for the current row, preventing the INSERT, UPDATE, or DELETE and suppressing subsequent triggers. For INSTEAD OF triggers on views, it signals that no modification was performed. While this behavior can be used for conditional logic (e.g., silently ignoring invalid rows), it presents a risk of unintended data loss or logic errors if used incorrectly. These triggers should be audited to ensure the cancellation behavior is intentional and correctly implemented.
Notes 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 triggers that procedure raises exception or has in addition to RETURN NULL also RETURN OLD or RETURN NEW.
Type General (Overview of some aspect of the database.)
License MIT License
Data Source INFORMATION_SCHEMA+system catalog
SQL Query
WITH Tr AS (SELECT
    n.nspname AS trigger_schema,
    t.tgname AS trigger_name,
    em.text AS event_manipulation,        
    c.relname AS trigger_table, 
	CASE WHEN c.relkind='r' THEN 'BASE TABLE'
	WHEN c.relkind='v' THEN 'VIEW'
	WHEN c.relkind='f' THEN 'FOREIGN TABLE'
	WHEN c.relkind='m' THEN 'MATERIALIZED VIEW'
	WHEN c.relkind='p' THEN 'PARTITIONED TABLE'	
	END AS table_type,
    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, table_type, action_timing, event_manipulation, action_orientation, action_condition, routine_name, regexp_replace(routine_definition,'[\r\n]','
','g') AS routine_definition FROM Tr WHERE action_timing IN ('BEFORE','INSTEAD OF') AND action_orientation='ROW' AND routine_definition~* 'RETURN[[:space:]]+NULL' AND routine_definition!~* 'RETURN[[:space:]]+(OLD|NEW)' AND routine_definition!~* 'RAISE[[:space:]]+EXCEPTION' ORDER BY trigger_schema, trigger_table, routine_name;
Categories

This query is classified under the following categories:

NameDescription
Triggers and rulesQueries of this category provide information about triggers and rules in a database.

Further reading and related materials:

Reference
https://www.postgresql.org/docs/current/plpgsql-trigger.html