Query goal: | Find enumerated types that are not used in case of any base table column, domain, and routine (input or otput) parameter (as their type). Do not keep in your database elements that are not needed by anybody. These should be put in use or dropped, otherwise these are dead code. |
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: | Use the type at least once or drop it. It is possible that an enumerated type is used as the type of a variable in a routine. In this case dropping the type succeeds although it invalidates the routine. |
Data source: | INFORMATION_SCHEMA+system catalog |
SQL query: | Click on query to copy it
WITH input_parameters AS (SELECT unnest(proargtypes) AS parameter_type FROM pg_proc), enumeration_types AS (SELECT t.oid, nspname AS type_schema, typname, array_agg(enumlabel ORDER BY enumsortorder) AS values FROM pg_catalog.pg_type t LEFT 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) AND t.typtype='e' GROUP BY t.oid, nspname, typname) SELECT type_schema, typname, values FROM enumeration_types AS et WHERE NOT EXISTS (SELECT 1 FROM pg_attribute WHERE pg_attribute.atttypid=et.oid) AND NOT EXISTS (SELECT 1 FROM pg_proc WHERE pg_proc.prorettype=et.oid) AND NOT EXISTS (SELECT 1 FROM input_parameters WHERE input_parameters.parameter_type=et.oid) AND NOT EXISTS (SELECT 1 FROM pg_type WHERE pg_type.typbasetype =et.oid) ORDER BY type_schema, typname; |
SQL query | Description |
---|---|
WITH input_parameters AS (SELECT unnest(proargtypes) AS parameter_type FROM pg_proc), enumeration_types AS (SELECT t.oid, n.nspname AS type_schema, t.typname AS type_name FROM pg_type AS t INNER JOIN pg_namespace AS n ON n.oid=t.typnamespace INNER JOIN pg_authid AS a ON n.nspowner=a.oid WHERE (n.nspname='public' OR rolname<>'postgres') AND t.typtype='e'), unused_types AS (SELECT type_schema, type_name FROM enumeration_types AS et WHERE NOT EXISTS (SELECT 1 FROM pg_attribute WHERE pg_attribute.atttypid=et.oid) AND NOT EXISTS (SELECT 1 FROM pg_proc WHERE pg_proc.prorettype=et.oid) AND NOT EXISTS (SELECT 1 FROM input_parameters WHERE input_parameters.parameter_type=et.oid) AND NOT EXISTS (SELECT 1 FROM pg_type WHERE pg_type.typbasetype =et.oid)) SELECT format('DROP TYPE %1$I.%2$I RESTRICT;', type_schema, type_name) AS statements FROM unused_types ORDER BY type_schema, type_name; | Drop the enumerated type. |
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. |
Unused implementation elements | Queries of this catergory provide information about the database objects that are not used. |
User-defined types | Queries of this category provide information about user-defined types in the database. |
Reference |
---|
https://en.wikipedia.org/wiki/Dead_code |
The corresponding code smells in case of cleaning code are "F4: Dead Function" and "G9: Dead Code". (Robert C. Martin, Clean Code) |