Goal Find row level update triggers that incorrectly implement update of password hash. It should not be that the new password hash is calculated based on the existing hash.
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 The trigger that calculates new password hash should not calculate it based on the existing hash. Moreover, the trigger should fire only in case of updating a value in the password column.
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 Tr.trigger_schema, trigger_table, action_timing, event_manipulation, action_orientation, action_condition, routine_name, regexp_replace(routine_definition,'[\r\n]','
','g') AS routine_definition, array_agg(event_object_column) AS update_columns FROM Tr LEFT JOIN information_schema.triggered_update_columns AS TUC ON Tr.trigger_schema=TUC.trigger_schema AND Tr.trigger_name=TUC.trigger_name AND Tr.trigger_table=TUC.event_object_table WHERE action_orientation='ROW' AND event_manipulation='UPDATE' AND routine_definition ~* 'crypt[(].+, gen_salt' AND routine_definition!~* 'if[[:space:]].*(new[.].+(<>|is[[:space:]]+distinct[[:space:]]+from).+old[.]).*[[:space:]]then' AND (action_condition!~*'(new[.].+(<>|is[[:space:]]+distinct[[:space:]]+from).+old[.])' OR action_condition IS NULL) GROUP BY Tr.trigger_schema, trigger_table, action_timing, event_manipulation, action_orientation, action_condition, routine_name, routine_definition ORDER BY Tr.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
SecurityQueries of this category provide information about the security measures.
Triggers and rulesQueries of this category provide information about triggers and rules in a database.