Goal Do not let the system to do extra work. Checking a constraint with an AFTER trigger means that the trigger procedure will be executed after the data modification and if the check fails, then the system has to do extra work to roll back the changes.
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 does not take into account constraint triggers because these should indeed be AFTER triggers.
Type Problem detection (Each row in the result could represent a flaw in the design)
Reliability Medium (Medium number of false-positive results)
License MIT License
Fixing Suggestion If you do not use constraint triggers for implementing check of a constraint, then use BEFORE triggers for this purpose.
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,
	EXISTS (SELECT 1 FROM pg_constraint AS c WHERE c.oid=t.tgconstraint AND c.contype='t') AS is_constraint_trigger
   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 is_constraint_trigger=FALSE AND action_timing='AFTER' AND action_orientation='ROW' AND routine_definition~* 'RAISE[[:space:]]+EXCEPTION' ORDER BY trigger_schema, trigger_table, routine_name;
Collections

This query belongs to the following collections:

NameDescription
Find problems automaticallyQueries, 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 .
Categories

This query is classified under the following categories:

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