Goal Find base table columns with an array type. Think through as to whether a column with an array type could be replaced with a separate table.
Notes The query takes into account a possibility that the type may be associated with the column through a domain. Translate function is used to clean the output and show the base type of array without extra characters.
Type General (Overview of some aspect of the database.)
License MIT License
Data Source INFORMATION_SCHEMA+system catalog
SQL Query
WITH array_domains AS (SELECT domain_schema, domain_name, data_type
FROM information_schema.domains 
WHERE data_type LIKE '%[]')
SELECT 
n.nspname AS table_schema,
c.relname AS table_name,
at.attname AS column_name,
NULL AS domain_name,
translate(t.typname,'_','') AS array_element_type
FROM pg_attribute at INNER JOIN pg_class c ON at.attrelid=c.oid
INNER JOIN pg_namespace AS n ON n.oid=c.relnamespace
INNER JOIN pg_authid AS a ON n.nspowner=a.oid
INNER JOIN pg_type AS t ON at.atttypid=t.oid
INNER JOIN pg_namespace AS n_type ON t.typnamespace=n_type.oid
WHERE (n.nspname='public' OR rolname<>'postgres')
AND c.relkind='r' 
AND at.attisdropped='f'
AND at.attnum>0
AND at.attndims<>0
UNION 
SELECT 
n.nspname AS table_schema,
c.relname AS table_name,
at.attname AS column_name,
t.typname AS domain_name,
translate(array_domains.data_type,'[]','') AS array_element_type
FROM pg_attribute at INNER JOIN pg_class c ON at.attrelid=c.oid
INNER JOIN pg_namespace AS n ON n.oid=c.relnamespace
INNER JOIN pg_authid AS a ON n.nspowner=a.oid
INNER JOIN pg_type AS t ON at.atttypid=t.oid
INNER JOIN pg_namespace AS n_type ON t.typnamespace=n_type.oid
INNER JOIN array_domains ON n_type.nspname=array_domains.domain_schema AND t.typname=array_domains.domain_name
WHERE (n.nspname='public' OR rolname<>'postgres')
AND c.relkind='r' 
AND at.attisdropped='f'
AND at.attnum>0
AND t.typtype='d'
ORDER BY table_schema, table_name, column_name;

Collections

This query belongs to the following collections:

NameDescription
Find problems by overviewQueries that results point to different aspects of database that might have problems. A human reviewer has to decide based on the results as to whether there are problems or not .
Categories

This query is classified under the following categories:

NameDescription
Data typesQueries of this category provide information about the data types and their usage.

Further reading and related materials:

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