Find multiple rules with the same definition (event, condition, action) on the same table. Do remember that the same task can be solved in SQL usually in multiple different ways. Thus, the exact copies are not the only possible duplication.
Notes
In case of the string_agg function, the line break (br) tag is used as a part of the separator for the better readability in case the query result is displayed in a web browser.
Type
Problem detection (Each row in the result could represent a flaw in the design)
All but one are redundant. Drop the redundant rules.
Data Source
system catalog only
SQL Query
SELECT schemaname, tablename, replace(definition, rulename, 'rulename') AS rule_definition,
string_agg(rulename, '; ' ORDER BY rulename) AS rules,
Count(*) AS number_of_rules
FROM pg_rules
GROUP BY schemaname, tablename, rule_definition
HAVING Count(*)>1
ORDER BY schemaname, tablename, Count(*) DESC;
SQL statements that help generate fixes for the identified problem.
SQL Query to Generate Fix
Description
WITH duplicate_rules AS (
SELECT schemaname, tablename, array_agg(rulename) AS rules_array
FROM pg_rules
GROUP BY schemaname, tablename, replace(definition, rulename, 'rulename')
HAVING Count(*)>1)
SELECT format('DROP RULE %1$I ON TABLE %2$I.%3$I;', unnest(rules_array), schemaname, tablename) AS statements
FROM duplicate_rules
ORDER BY schemaname, tablename, unnest(rules_array);
Drop the rule. One of the rules must stay in place.
Collections
This query belongs to the following collections:
Name
Description
Find problems automatically
Queries, 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:
Name
Description
Duplication of implementation elements
Queries of this catergory provide information about the duplication of the database objects.
Triggers and rules
Queries of this category provide information about triggers and rules in a database.