The list of all the queries

Insufficient number of user-defined triggers+rules (based on number of tasks)

Query goal: There must be user-defined triggers and/or rules for at least n (three in this case) tasks in the database.
Notes about the query: The query excludes DO INSTEAD NOTHING rules.
Query type: Problem detection (Each row in the result could represent a flaw in the design)
Query reliability: Medium (Medium number of false-positive results)
Query license: MIT License
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,
	EXISTS (SELECT 1 FROM pg_constraint AS c WHERE c.oid=t.tgconstraint AND c.contype='t') AS is_constraint_trigger,
	 t.tginitdeferred AS is_init_deferred
   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)),
rules AS (SELECT 
  r.definition
FROM 
  pg_catalog.pg_rules r, 
  pg_catalog.pg_namespace n, 
  pg_catalog.pg_authid u
WHERE 
  r.schemaname = n.nspname AND
  n.nspowner = u.oid AND 
 (n.nspname = 'public' OR u.rolname <> 'postgres')
 AND r.definition!~'DO[[:space:]]+INSTEAD[[:space:]]+NOTHING')  
SELECT 'Too few triggers/rules, must be at least three - triggers/rules that do the same thing are counted as one.' As comment, 
(SELECT Count(DISTINCT routine_definition) AS cnt FROM Tr)+(SELECT Count(DISTINCT definition) AS cnt FROM rules) AS the_number_of_tasks
WHERE (SELECT Count(DISTINCT routine_definition) AS cnt FROM Tr)+(SELECT Count(DISTINCT definition) AS cnt FROM rules)<3;

Collections where the query belongs to

Collection nameCollection description
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 where the query belongs to

Category nameCategory description
AssessmentQueries of this category could be used specifically in the learning environment to assess as to whether student projects have filled certain criteria.
Triggers and rulesQueries of this category provide information about triggers and rules in a database.

The list of all the queries