The list of all the queries

NOT NULL domains

Query goal: Find domains with NOT NULL constraints and base table columns that have been defined based on the domain. PostgreSQL CREATE DOMAIN statement documentation points out that it is possible to add NULL's to columns that have a NOT NULL domain and thus suggests to associate NOT NULL constraints with a column instead of the domain. However, this is a non-standard behavior and defeats the idea of domain as a reusable asset. The scenarios where NULLs can appear in columns with a NOT NULL domain are quite exotic and probably cannot appear in production environments.
Query type: General (Overview of some aspect of the database.)
Query license: MIT License
Data source: INFORMATION_SCHEMA+system catalog
SQL query: Click on query to copy it

WITH domains_not_null AS (SELECT pg_namespace.nspname AS domain_schema, pg_type.typname AS domain_name 
FROM pg_catalog.pg_type,  pg_catalog.pg_namespace
WHERE pg_namespace.oid = pg_type.typnamespace AND pg_type.typnotnull = TRUE
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)),

col_domains_not_null AS (SELECT d.domain_schema, d.domain_name, c.table_schema, c.table_name, c.column_name
FROM domains_not_null AS d INNER JOIN
Information_schema.column_domain_usage AS du USING (domain_schema, domain_name)
INNER JOIN Information_schema.columns AS c USING (table_schema, table_name, column_name)
WHERE c.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 
(table_schema, table_name) IN (SELECT table_schema, table_name 
FROM INFORMATION_SCHEMA.tables WHERE table_type='BASE TABLE'))

SELECT domain_schema, domain_name, string_agg(table_schema || '.' || table_name || '.' || column_name,';<br>' ORDER BY table_schema, table_name, column_name) AS base_table_columns
FROM col_domains_not_null
GROUP BY domain_schema, domain_name
ORDER BY domain_schema, domain_name;

Collections where the query belongs to

Collection nameCollection description
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 where the query belongs to

Category nameCategory description
DomainsQueries of this category provide information about reusable specifications of column properties.
Missing dataQueries of this category provide information about missing data (NULLs) in a database.

Reference materials for further reading

Reference
https://www.postgresql.org/docs/current/sql-createdomain.html

The list of all the queries