Query goal: | Find enumerated types with exactly the same values. There should not be multiple types that have the same values. |
Notes about the query: | The query takes into account that the sort order of values in different enumerated types could be different. For instance, the query considers types ("A", "B") and ("B", "A") as duplicates. In case of each enumerated type the query forms a list of type values that has been sorted based on the labels and uses it as the basis for grouping. |
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: | All but one are redundant. Drop all the types except one and use the type in case of all the columns that need the type. |
Data source: | INFORMATION_SCHEMA+system catalog |
SQL query: | Click on query to copy it
WITH enum_types AS (SELECT nspname AS type_schema, typname, array_agg(enumlabel ORDER BY enumlabel) AS values FROM pg_catalog.pg_type t INNER JOIN pg_catalog.pg_enum e ON t.oid=e.enumtypid INNER JOIN pg_catalog.pg_namespace n ON n.oid=t.typnamespace WHERE nspname 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 nspname, typname) SELECT values, string_agg(type_schema || '.' || typname, ';<br>' ORDER BY type_schema, typname) AS types FROM enum_types GROUP BY values HAVING Count(*)>1 ORDER BY Count(*) DESC; |
SQL query | Description |
---|---|
WITH enum_types AS (SELECT nspname AS type_schema, typname, array_agg(enumlabel ORDER BY enumlabel) AS values FROM pg_catalog.pg_type t INNER JOIN pg_catalog.pg_enum e ON t.oid=e.enumtypid INNER JOIN pg_catalog.pg_namespace n ON n.oid=t.typnamespace WHERE nspname 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 nspname, typname), duplicate_enum_types AS (SELECT array_agg(type_schema || '.' || typname ORDER BY type_schema, typname) AS types_array FROM enum_types GROUP BY values HAVING Count(*)>1) SELECT format('DROP TYPE %1$s;', unnest(types_array)) AS statements FROM duplicate_enum_types ORDER BY statements; | Drop the type. One of the types 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 |
---|---|
Comfortability of database evolution | Queries of this category provide information about the means that influence database evolution. |
Data types | Queries of this category provide information about the data types and their usage. |
Duplication of implementation elements | Queries of this catergory provide information about the duplication of the database objects. |
User-defined types | Queries of this category provide information about user-defined types in the database. |
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) |