WITH checks AS (SELECT ccu.table_schema, ccu.table_name, ccu.column_name
FROM INFORMATION_SCHEMA.constraint_column_usage AS ccu INNER JOIN INFORMATION_SCHEMA.check_constraints AS cc USING (constraint_schema, constraint_name)
WHERE cc.check_clause NOT LIKE '%IS NOT NULL' AND
ccu.table_schema NOT IN (SELECT schema_name
FROM INFORMATION_SCHEMA.schemata
WHERE schema_name<>'public' AND
schema_owner='postgres' AND schema_name IS NOT NULL)
UNION SELECT cdu.table_schema, cdu.table_name, cdu.column_name
FROM INFORMATION_SCHEMA.column_domain_usage AS cdu INNER JOIN INFORMATION_SCHEMA.tables AS t USING (table_schema, table_name)
INNER JOIN INFORMATION_SCHEMA.domain_constraints AS dc USING (domain_schema, domain_name)
INNER JOIN INFORMATION_SCHEMA.check_constraints AS cc USING (constraint_schema, constraint_name)
WHERE t.table_type IN ('BASE TABLE','FOREIGN') AND cc.check_clause NOT LIKE '%IS NOT NULL' AND
cdu.table_schema NOT IN (SELECT schema_name
FROM INFORMATION_SCHEMA.schemata
WHERE schema_name<>'public' AND
schema_owner='postgres' AND schema_name IS NOT NULL)),
fk AS (SELECT
(SELECT nspname FROM pg_namespace WHERE oid=c.relnamespace) AS key_schema,
c.relname AS key_table,
o.conkey AS key_col,
c.oid AS key_table_oid
FROM pg_constraint o INNER JOIN pg_class c ON c.oid = o.conrelid
WHERE o.contype='f'),
fk_unnest AS (SELECT key_schema, key_table, key_table_oid, key_col, key_col_num, ordin
FROM fk, unnest(fk.key_col) with ordinality AS k(key_col_num, ordin)),
fk_with_names AS (SELECT key_schema AS table_schema, key_table AS table_name, a_key.attname AS column_name
FROM fk_unnest k inner join pg_attribute a_key ON k.key_col_num = a_key.attnum AND k.key_table_oid = a_key.attrelid AND a_key.attisdropped = FALSE),
checks_not_on_fk_columns AS (SELECT table_schema, table_name, column_name
FROM checks
EXCEPT SELECT table_schema, table_name, column_name
FROM fk_with_names)
SELECT table_schema, table_name, table_type
FROM INFORMATION_SCHEMA.tables AS t
WHERE table_type IN ('BASE TABLE', 'FOREIGN')
AND table_schema NOT IN (SELECT schema_name
FROM INFORMATION_SCHEMA.schemata
WHERE schema_name<>'public' AND
schema_owner='postgres' AND schema_name IS NOT NULL)
AND NOT EXISTS (SELECT 1
FROM checks_not_on_fk_columns AS ch
WHERE ch.table_schema=t.table_schema AND ch.table_name=t.table_name)
AND EXISTS (SELECT *
FROM INFORMATION_SCHEMA.columns AS c
WHERE (table_schema, table_name, column_name) NOT IN (
SELECT table_schema, table_name, column_name
FROM fk_with_names)
AND c.table_schema=t.table_schema
AND c.table_name=t.table_name)
ORDER BY table_schema, table_name;