The list of all the queries

Unused composite types (for table columns, typed tables, input and output parameters)

Query goal: Find user-defined composite types that are not used in case of any 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 type at least once or drop it. It is possible that a composite 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: 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 type_schema,
t.typname AS type_name,
(SELECT string_agg(attname || ' ' || typname, ', ' ORDER BY attnum) AS type_structure
FROM pg_attribute INNER JOIN pg_type ON pg_attribute.atttypid=pg_type.oid
WHERE pg_attribute.attrelid=t.typrelid
AND pg_attribute.attisdropped='f'
AND pg_attribute.attnum>0) AS type_structure
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='c'
AND NOT EXISTS (SELECT 1
FROM pg_class
WHERE pg_class.reltype=t.oid
AND pg_class.relkind<>'c')
AND NOT EXISTS (SELECT 1
FROM pg_class
WHERE pg_class.reloftype=t.oid)
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 type_schema, type_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_composite_types AS (SELECT 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='c'
AND NOT EXISTS (SELECT 1
FROM pg_class
WHERE pg_class.reltype=t.oid
AND pg_class.relkind<>'c')
AND NOT EXISTS (SELECT 1
FROM pg_class
WHERE pg_class.reloftype=t.oid)
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 TYPE %1$I.%2$I RESTRICT;', type_schema, type_name) AS statements
  FROM unused_composite_types
ORDER BY type_schema, type_name;
Drop the composite type.

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
Data typesQueries of this category provide information about the data types and their usage.
Unused implementation elementsQueries of this catergory provide information about the database objects that are not used.
User-defined typesQueries of this category provide information about user-defined types in the database.

Reference materials for further reading

Reference
https://www.postgresql.org/docs/current/rowtypes.html

The list of all the queries