Goal This query identifies trigger functions intended for constraint enforcement that are susceptible to concurrency anomalies due to PostgreSQL's Multi-Version Concurrency Control (MVCC) model. Since read operations (SELECT) do not block write operations, a trigger that validates cross-row constraints without acquiring explicit locks (e.g., LOCK TABLE or SELECT ... FOR UPDATE) involves a race condition. The query detects triggers that query auxiliary data.
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.
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, 
    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]','
','g') AS routine_definition FROM Tr WHERE routine_definition~*'select[[:space:]][^;]+from' ORDER BY trigger_schema, trigger_table, routine_name;
Categories

This query is classified under the following categories:

NameDescription
TransactionsQueries of this catergory provide information about the use of transactions.
Triggers and rulesQueries of this category provide information about triggers and rules in a database.