The list of all the queries

Do not leave out referential constraints (based on composite keys)

Query goal: Try to find missing foreign key constraints. Find columns of base tables that are not covered by any foreign key constraint but belong to a composite key, do not have an associated sequence generator, and have a name that refers to the possibility that these are used to record some kind of codes or id's. Moreover, there must be at least one other base table that has a column with the same name. Such strategy would find missing constraints in tables that implement many-to-many relationship types but which that are not complete "islands" in terms of missing foreign key constraints.
Query type: Problem detection (Each row in the result could represent a flaw in the design)
Query reliability: Medium (Medium number of false-positive results)
Query license: MIT License
Fixing suggestion: Declare the missing foreign key constraint.
Data source: INFORMATION_SCHEMA+system catalog
SQL query: Click on query to copy it

WITH fkey AS (SELECT 
(SELECT nspname FROM pg_namespace WHERE oid=c.relnamespace) AS key_schema,
c.relname AS key_table, 
o.conkey AS key_col,
c.oid AS key_table_oid
FROM pg_constraint o INNER JOIN pg_class c ON c.oid = o.conrelid
WHERE o.contype IN ('f')),
fkey_unnest AS (SELECT key_schema, key_table, key_table_oid, key_col, key_col_num, ordin
FROM fkey, unnest(fkey.key_col) with ordinality AS k(key_col_num, ordin)),
fkey_with_names AS (SELECT key_schema, key_table, a_key.attname AS key_col
FROM fkey_unnest k INNER JOIN pg_attribute a_key ON k.key_col_num = a_key.attnum AND k.key_table_oid = a_key.attrelid AND a_key.attisdropped = FALSE),
keys as (select 
(select nspname from pg_namespace where oid=c.relnamespace) as key_schema,
c.relname as key_table, 
c.oid as key_table_oid,
o.conkey AS key_col
from pg_constraint o inner join pg_class c on c.oid = o.conrelid
where o.contype in ('u', 'p') and cardinality(o.conkey)>1),
keys_unnest as (select key_schema, key_table, key_table_oid, key_col, key_col_num, ordin
from keys, unnest(keys.key_col) with ordinality as k(key_col_num, ordin)),
keys_with_names as (select key_schema, key_table, a_key.attname as key_col
from keys_unnest k inner join pg_attribute a_key on k.key_col_num = a_key.attnum and k.key_table_oid = a_key.attrelid and a_key.attisdropped = false),
surrogate_key AS (SELECT c.table_schema, c.table_name , c.column_name
FROM information_schema.columns c
LEFT JOIN information_schema.domains d USING (domain_schema, domain_name)
INNER JOIN information_schema.schemata s
ON c.table_schema=s.schema_name
WHERE  (coalesce (c.column_default, d.domain_default) ILIKE '%nextval%'  OR c.is_identity='YES')
AND (c.table_schema = 'public'
OR s.schema_owner<>'postgres'))

SELECT table_schema, table_name, column_name, data_type
FROM INFORMATION_SCHEMA.columns AS c
WHERE 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')
AND (column_name~*'_id$'
OR column_name~*'.+(kood|code)$'
OR column_name~*'^(kood|code|id|k)_')
AND NOT EXISTS (SELECT 1
FROM fkey_with_names AS kwn
WHERE c.table_schema=kwn.key_schema
AND c.table_name=kwn.key_table
AND c.column_name=kwn.key_col)
AND NOT EXISTS (SELECT 1
FROM surrogate_key AS sk
WHERE c.table_schema=sk.table_schema
AND c.table_name=sk.table_name
AND c.column_name=sk.column_name)
AND EXISTS (SELECT 1
FROM keys_with_names AS kwn
WHERE c.table_schema=kwn.key_schema
AND c.table_name=kwn.key_table
AND c.column_name=kwn.key_col)
AND EXISTS (SELECT *
FROM INFORMATION_SCHEMA.columns AS co
WHERE 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')
AND c.table_schema || '.' || c.table_name<>co.table_schema || '.' || co.table_name
AND c.column_name=co.column_name)
ORDER BY table_schema, table_name, ordinal_position;

Collections where the query belongs to

Collection nameCollection description
Find problems about base tablesA selection of queries that return information about the data types, field sizes, default values as well as general structure of base tables. 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
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.
Result quality depends on namesQueries of this category use names (for instance, column names) to try to guess the meaning of a database object. Thus, the goodness of names determines the number of false positive and false negative results.
UniquenessQueries of this category provide information about uniqueness constraints (PRIMARY KEY, UNIQUE, EXCLUDE) as well as unique indexes.

The list of all the queries