Find the base tables where all the unique columns are optional. In such tables there can be rows without values that identify these rows. In this case there can be rows in the table where the values that should identify the row are missing.
Type
Problem detection (Each row in the result could represent a flaw in the design)
WITH unique_columns AS (SELECT
n.nspname AS table_schema,
c2.relname AS table_name,
a.attname AS column_name
FROM
pg_catalog.pg_class AS c INNER JOIN pg_catalog.pg_index AS i ON i.indexrelid = c.oid
INNER JOIN pg_catalog.pg_class AS c2 ON i.indrelid = c2.oid
INNER JOIN pg_catalog.pg_namespace AS n ON c.relnamespace = n.oid
INNER JOIN pg_catalog.pg_authid AS u ON n.nspowner = u.oid
INNER JOIN pg_catalog.pg_attribute AS a ON a.attrelid = c.oid
WHERE c.relkind = 'i'
AND i.indisunique=TRUE
AND a.attnum>=1
AND a.attisdropped = FALSE
AND (n.nspname = 'public'
OR u.rolname <> 'postgres'))
SELECT A.table_schema, A.table_name
FROM unique_columns AS U INNER JOIN information_schema.columns A USING (table_schema, table_name, column_name)
INNER JOIN information_schema.tables T USING (table_schema, table_name)
INNER JOIN information_schema.schemata S ON A.table_schema=S.schema_name
WHERE T.table_type='BASE TABLE'
AND (A.table_schema = 'public'
OR S.schema_owner<>'postgres')
GROUP BY A.table_schema, A.table_name
HAVING Count(*)=Count(*) FILTER (WHERE is_nullable='YES')
ORDER BY table_schema, table_name;
Collections
This query belongs to the following collections:
Name
Description
Find problems about integrity constraints
A selection of queries that return information about the state of integrity constraints in the datadabase. Contains all the types of queries - problem detection, software measure, and general overview
Find problems automatically
Queries, 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
This query is classified under the following categories:
Name
Description
Missing data
Queries of this category provide information about missing data (NULLs) in a database.
Validity and completeness
Queries of this category provide information about whether database design represents the world (domain) correctly (validity) and whether database design captures all the information about the world (domain) that is correct and relevant (completeness).