WITH columns AS (SELECT nspname AS table_schema, relname AS table_name,
CASE WHEN relkind='r' THEN 'BASE TABLE'
WHEN relkind='v' THEN 'VIEW'
WHEN relkind='m' THEN 'MATERIALIZED VIEW'
WHEN relkind='f' THEN 'FOREIGN TABLE'
WHEN relkind='p' THEN 'PARTITIONED TABLE'
END AS table_type,
attname AS column_name,
CASE WHEN typbasetype=0 THEN pg_type.typname
ELSE (SELECT typname
FROM pg_type AS domain_type
WHERE domain_type.oid=pg_type.typbasetype) END AS column_type,
CASE WHEN attndims<>0 OR typndims<>0 THEN TRUE ELSE FALSE END AS is_array
FROM pg_class INNER JOIN pg_namespace ON pg_class.relnamespace=pg_namespace.oid
INNER JOIN pg_attribute ON pg_class.oid=pg_attribute.attrelid
INNER JOIN pg_type ON pg_attribute.atttypid =pg_type.oid
WHERE attnum>=1
AND relkind IN ('r','v','m','f','p')
AND nspname NOT IN (SELECT schema_name
FROM INFORMATION_SCHEMA.schemata
WHERE schema_name<>'public' AND
schema_owner='postgres' AND schema_name IS NOT NULL)),
plural_or_singular AS (SELECT table_schema, table_name, table_type, column_name,
CASE WHEN is_array=FALSE THEN column_type ELSE 'ARRAY [' || translate(column_type,'_','') || ']' END AS column_type,
CASE WHEN (regexp_replace(column_name,'(stats_|stats$|status|state|is_|has_|pos$|alias|cvs|address|value$|key$|pays$|group$|lock$|_to$|_id$|_code$|_type$|_name$|posts_to|sales_tax|trans_type|_date$|_time$|_flag$|number|sys|class$|basis$|needs)','','g') ~* '(?<!((^|_)[[:alnum:]]{0,2}|(^|_)[bcdfghjklmnpqrsztvwxz]{0,4}|s))s(_|$)' OR column_name~*'(ids|codes)$') AND column_name!~*'(key|value|group)$' THEN 'Perhaps plural' ELSE 'Perhaps singular' END AS comment_about_the_column_name
FROM columns),
plural_singular_evaluation AS
(SELECT table_schema, table_name, table_type, column_name, column_type, comment_about_the_column_name,
CASE WHEN comment_about_the_column_name='Perhaps plural' AND column_type!~*'(array|json|xml|int|numeric|float)' THEN 'Perhaps should be singular'
WHEN comment_about_the_column_name='Perhaps singular' AND column_type~*'(array|json|xml)' THEN 'Perhaps should be plural'
ELSE 'OK' END AS evaluation
FROM plural_or_singular)
SELECT table_type, comment_about_the_column_name, evaluation, Count(*) AS nr_of_columns
FROM plural_singular_evaluation
GROUP BY ROLLUP (table_type, comment_about_the_column_name, evaluation)
ORDER BY table_type, Count(*) DESC, comment_about_the_column_name, evaluation;