Goal Find base tables where all the columns are optional, i.e., permit NULLs. In such tables can be rows with no identity value and thus indistinguishable from other rows.
Type Problem detection (Each row in the result could represent a flaw in the design)
Reliability High (Few or no false-positive results)
License MIT License
Fixing Suggestion Find columns that must be mandatory and declare to these NOT NULL constraint. Declare the primary key because primary key columns are automatically mandatory.
Data Source INFORMATION_SCHEMA only
SQL Query
SELECT table_schema, table_name
FROM information_schema.columns AS c INNER JOIN INFORMATION_SCHEMA.tables AS t USING  (table_schema, table_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_type='BASE TABLE'
GROUP BY table_schema, table_name
HAVING Count(*) = Count(*) FILTER (WHERE is_nullable='YES')
ORDER BY table_schema, table_name;

Collections

This query belongs to the following collections:

NameDescription
Find problems about integrity constraintsA 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 automaticallyQueries, 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:

NameDescription
Missing dataQueries of this category provide information about missing data (NULLs) in a database.
Validity and completenessQueries 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).