Query goal: | The same domain should not have multiple CHECK constraints with exactly the same Boolean expression. 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 about the query: | 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. |
Query type: | Problem detection (Each row in the result could represent a flaw in the design) |
Query reliability: | High (Few or no false-positive results) |
Query license: | MIT License |
Fixing suggestion: | Drop the redundant constraints. |
Data source: | INFORMATION_SCHEMA only |
SQL query: | Click on query to copy it
WITH checks AS (SELECT dc.domain_schema, dc.domain_name, cc.constraint_name, cc.check_clause FROM INFORMATION_SCHEMA.domain_constraints AS dc INNER JOIN INFORMATION_SCHEMA.domains AS d USING (domain_schema, domain_name) INNER JOIN INFORMATION_SCHEMA.check_constraints AS cc USING (constraint_schema, constraint_name) WHERE cc.check_clause NOT LIKE '%IS NOT NULL' AND dc.domain_schema NOT IN (SELECT schema_name FROM INFORMATION_SCHEMA.schemata WHERE schema_name<>'public' AND schema_owner='postgres' AND schema_name IS NOT NULL)) SELECT domain_schema, domain_name, check_clause, Count(*) AS number_of_occurrences, string_agg(constraint_name, ';<br>' ORDER BY constraint_name) AS constraints FROM checks GROUP BY domain_schema, domain_name, check_clause HAVING Count(*)>1 ORDER BY Count(*) DESC, domain_schema, domain_name; |
SQL query | Description |
---|---|
WITH duplicate_checks AS (SELECT dc.domain_schema, dc.domain_name, cc.check_clause, array_agg(DISTINCT cc.constraint_name) AS constraints_array FROM INFORMATION_SCHEMA.domain_constraints AS dc INNER JOIN INFORMATION_SCHEMA.domains AS d USING (domain_schema, domain_name) INNER JOIN INFORMATION_SCHEMA.check_constraints AS cc USING (constraint_schema, constraint_name) WHERE cc.check_clause NOT LIKE '%IS NOT NULL' AND dc.domain_schema NOT IN (SELECT schema_name FROM INFORMATION_SCHEMA.schemata WHERE schema_name<>'public' AND schema_owner='postgres' AND schema_name IS NOT NULL) GROUP BY dc.domain_schema, dc.domain_name, cc.check_clause HAVING Count(DISTINCT cc.constraint_name)>1) SELECT format ('ALTER DOMAIN %1$I.%2$I DROP CONSTRAINT %3$I;', domain_schema, domain_name, unnest(constraints_array)) AS statements FROM duplicate_checks ORDER BY domain_schema, domain_name; | Drop the constraint. One of the constraints must stay in place. |
Collection name | Collection 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 . |
Category name | Category description |
---|---|
CHECK constraints | Queries of this category provide information about CHECK constraints. |
Domains | Queries of this category provide information about reusable specifications of column properties. |
Duplication of implementation elements | Queries of this catergory provide information about the duplication of the database objects. |
Reference |
---|
https://refactoring.guru/smells/alternative-classes-with-different-interfaces |
https://refactoring.guru/smells/duplicate-code |
The corresponding code smell in case of cleaning code is "G5: Duplication". (Robert C. Martin, Clean Code) |