The list of all the queries

Optional foreign key columns

Query goal: Find foreign key columns that do not have the NOT NULL constraint. It is better to limit the use of NULLs and optional columns due to the problems that it causes in interpreting the query results, making queries, and enforcing constraints. In addition, one should check as to whether this kind of design is consistent with the multiplicities in the conceptual data model.
Notes about the query: The query does not take into account a possibility that the column has been declared mandatory by using a CHECK constraint that is associated directly to the table or is associated with the table through a domain.
Query type: General (Overview of some aspect of the database.)
Query license: MIT License
Fixing suggestion: Declare the column mandatory. It the column already contains NULLs, then declare a NOT VALID check constraint that the values in the column must be NOT NULL. If the constraint has such constraint, then new data is checked against the constraint but the existing data is not checked.
Data source: INFORMATION_SCHEMA only
SQL query: Click on query to copy it

SELECT A.table_schema, A.table_name , A.column_name, A.constraint_name AS foreign_key_constraint_name
FROM information_schema.key_column_usage A INNER JOIN information_schema.table_constraints B USING (table_schema, table_name, constraint_name)
INNER JOIN information_schema.columns C USING (table_schema, table_name, column_name)
INNER JOIN information_schema.schemata D ON A.table_schema=D.schema_name
WHERE B.constraint_type='FOREIGN KEY'
AND C.is_nullable = 'YES'
AND (A.table_schema = 'public'
OR D.schema_owner<>'postgres')
ORDER BY A.table_schema, A.table_name, C.ordinal_position;

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

SQL queryDescription
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.key_column_usage A INNER JOIN information_schema.table_constraints B USING (table_schema, table_name, constraint_name)
INNER JOIN information_schema.columns C USING (table_schema, table_name, column_name)
INNER JOIN information_schema.schemata D ON A.table_schema=D.schema_name
WHERE B.constraint_type='FOREIGN KEY'
AND C.is_nullable = 'YES'
AND (A.table_schema = 'public'
OR D.schema_owner<>'postgres')
ORDER BY A.table_schema, A.table_name, C.ordinal_position;
Declare the NOT NULL constraint to the column.
SELECT format('ALTER TABLE %1$I.%2$I ADD CONSTRAINT chk_%1$s_%2$s_not_null CHECK (%3$I IS NOT NULL) NOT VALID;', A.table_schema, A.table_name , A.column_name) AS statements
FROM information_schema.key_column_usage A INNER JOIN information_schema.table_constraints B USING (table_schema, table_name, constraint_name)
INNER JOIN information_schema.columns C USING (table_schema, table_name, column_name)
INNER JOIN information_schema.schemata D ON A.table_schema=D.schema_name
WHERE B.constraint_type='FOREIGN KEY'
AND C.is_nullable = 'YES'
AND (A.table_schema = 'public'
OR D.schema_owner<>'postgres')
ORDER BY A.table_schema, A.table_name, C.ordinal_position;
Declare the NOT VALID CHECK constraint.

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 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
Missing dataQueries of this category provide information about missing data (NULLs) in a database.
Relationships between tablesQueries of this category provide information about how database tables are connected to each other and whether such connections have been explicitly defined and whether it has been done correctly.
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).

Reference materials for further reading

Reference
http://www.dbdebunk.com/2017/04/null-value-is-contradiction-in-terms.html

The list of all the queries