The list of all the queries

Optional base table columns that participate in a UNIQUE constraint or index

Query goal: Find optional base table columns that participate in a UNIQUE constraint or index. Each base table has one or more candidate keys. One of these is usually selected to be the primary key, other are called alternate keys. To enforce an alternate key one should define a UNIQUE constraint and determine that all the key columns are mandatory (NOT NULL) just like the primary key columns are mandatory. Make sure that the NOT NULL constraint is not missing on these columns.
Query type: Problem detection (Each row in the result could represent a flaw in the design)
Query reliability: Low (Many false-positive results)
Query license: MIT License
Fixing suggestion: Declare the NOT NULL constraint if it is missing. If the column is associated with a domain, then decide as to wheter to associate the NOT NULL constraint with the domain instead of declaring it directly to the column.
Data source: INFORMATION_SCHEMA+system catalog
SQL query: Click on query to copy it

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 , A.column_name, CASE WHEN A.data_type ILIKE 'character%' AND A.character_maximum_length IS NOT NULL THEN A.data_type || '(' || A.character_maximum_length::text || ')'
WHEN A.data_type ILIKE 'timestamp%' AND A.datetime_precision IS NOT NULL THEN A.data_type || '(' || A.datetime_precision || ')'
WHEN A.data_type ILIKE 'numeric%' AND A.numeric_precision IS NOT NULL THEN A.data_type || '(' || A.numeric_precision::text || ',' ||coalesce(A.numeric_scale,0)::text || ')'
WHEN A.data_type ILIKE 'interval%' AND A.interval_type IS NOT NULL THEN A.data_type || '(' || A.interval_type::text || ')'
WHEN A.data_type='USER-DEFINED' THEN A.udt_schema || '.' || A.udt_name 
ELSE A.data_type END AS data_type
FROM information_schema.columns A 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 is_nullable='YES'
AND T.table_type='BASE TABLE'
AND (A.table_schema = 'public'
OR S.schema_owner<>'postgres')
AND (table_schema, table_name, column_name) IN (SELECT table_schema, table_name, column_name
FROM unique_columns)
ORDER BY table_schema, table_name, ordinal_position;

SQL statements for generating SQL statements that help us to fix the problem

SQL queryDescription
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 format('ALTER TABLE  %1$I.%2$I ALTER COLUMN %3$I SET NOT NULL;', A.table_schema, A.table_name , A.column_name) AS statements
FROM information_schema.columns A 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 is_nullable='YES'
AND T.table_type='BASE TABLE'
AND (A.table_schema = 'public'
OR S.schema_owner<>'postgres')
AND (table_schema, table_name, column_name) IN (SELECT table_schema, table_name, column_name
FROM unique_columns)
ORDER BY table_schema, table_name, ordinal_position;
Declare NOT NULL constraint to the column.

Collections where the query belongs to

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

Category nameCategory description
Missing dataQueries of this category provide information about missing data (NULLs) in a database.
UniquenessQueries of this category provide information about uniqueness constraints (PRIMARY KEY, UNIQUE, EXCLUDE) as well as unique indexes.
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).

The list of all the queries