The list of all the queries

Unused domains (for base table columns and parameters)

Query goal: Find domains that are not used in case of any base table column 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 domain at least once or drop it. It is possible that a domain is used as the type of a variable in a routine. In this case dropping the domain succeeds although it invalidates the routine.
Data source: system catalog only
SQL query: Click on query to copy it

WITH input_parameters AS (SELECT unnest(proargtypes) AS parameter_type
FROM pg_proc)
SELECT n.nspname AS domain_schema,
t.typname AS domain_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='d'
AND NOT EXISTS (SELECT 1
FROM pg_attribute 
WHERE pg_attribute.atttypid=t.oid)
AND NOT EXISTS (SELECT 1
FROM pg_proc 
WHERE pg_proc.prorettype=t.oid)
AND NOT EXISTS (SELECT 1
FROM input_parameters 
WHERE input_parameters.parameter_type=t.oid)
ORDER BY domain_schema, domain_name;

SQL statements for generating SQL statements that help us to fix the problem

SQL queryDescription
WITH input_parameters AS (SELECT unnest(proargtypes) AS parameter_type
FROM pg_proc),
unused_domains AS (SELECT n.nspname AS domain_schema,
t.typname AS domain_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='d'
AND NOT EXISTS (SELECT 1
FROM pg_attribute 
WHERE pg_attribute.atttypid=t.oid)
AND NOT EXISTS (SELECT 1
FROM pg_proc 
WHERE pg_proc.prorettype=t.oid)
AND NOT EXISTS (SELECT 1
FROM input_parameters 
WHERE input_parameters.parameter_type=t.oid))
SELECT format('DROP DOMAIN %1$I.%2$I RESTRICT;', domain_schema, domain_name) AS statements
FROM unused_domains
ORDER BY  domain_schema, domain_name ;
Drop the domain.

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
Comfortability of database evolutionQueries of this category provide information about the means that influence database evolution.
DomainsQueries of this category provide information about reusable specifications of column properties.
Unused implementation elementsQueries of this catergory provide information about the database objects that are not used.

Reference materials for further reading

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)

The list of all the queries