The list of all the queries

Do not leave out the referential constraints (based on column names)

Query goal: Try to find missing foreign key constraints. Find columns of base tables that are not a part of any primary key, unique, and foreign key constraint, do not have an associated sequence generator, but have a name that reffers to the possibility that these are used to record some kind of codes or id's.
Notes about the query: The query considers both column names in English and Estonian. The query excludes columns like sql_code and source_code.
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 foreign key constraint if it is missing. Rename the column if it does not contain codes or id's.
Data source: INFORMATION_SCHEMA+system catalog
SQL query: Click on query to copy it

WITH key 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','u','p')),
key_unnest AS (SELECT key_schema, key_table, key_table_oid, key_col, key_col_num, ordin
FROM key, unnest(key.key_col) with ordinality AS k(key_col_num, ordin)),
key_with_names AS (SELECT key_schema, key_table, a_key.attname AS key_col
FROM key_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~*'.+((?<!(sql|lähte|lahte)[_]*)kood|(?<!(sql|source)[_]*)code)$'
OR column_name~*'^(kood|code|id|k)_')
AND NOT EXISTS (SELECT 1
FROM key_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)
ORDER BY table_schema, table_name, ordinal_position;

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
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.
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
This is one of the antipatterns from the Bill Karwin's book of SQL antipatterns. See Chapter 5: Keyless Entry.
Blaha, M.: A retrospective on industrial database reverse engineering projects - part 2. In: Eighth Working Conference on Reverse Engineering, pp. 147–153. IEEE, (2001). https://doi.org/10.1109/WCRE.2001.957818 (Lack of declared foreign keys)
Blaha, M.R., Premerlani, W.J.: Observed idiosyncracies of relational database designs. In: 2nd Working Conference on Reverse Engineering, pp. 116–125. IEEE, (1995). https://doi.org/10.1109/WCRE.1995.514700 (Informal linkage between tables)
Weber, J.H., Cleve, A., Meurice, L., Ruiz, F.J.B.:. Managing technical debt in database schemas of critical software. In: Sixth International Workshop on Managing Technical Debt, pp. 43-46. IEEE (2014).
Al-Barak, M., Bahsoon, R.: Database design debts through examining schema evolution. In: 8th International Workshop on Managing Technical Debt, pp. 17–23. IEEE, (2016). https://doi.org/10.1109/MTD.2016.9 (Lack of declared foreign keys)
Rule 7 in: Delplanque, J., Etien, A., Auverlot, O., Mens, T., Anquetil, N., Ducasse, S.: CodeCritics applied to database schema: Challenges and first results. In: 2017 IEEE 24th International Conference on Software Analysis, Evolution and Reengineering (SANER), pp. 432-436. IEEE, (2017).
Smell "Missing constraints": Sharma, T., Fragkoulis, M., Rizou, S., Bruntink, M. and Spinellis, D.: Smelly relations: measuring and understanding database schema quality. In: Proceedings of the 40th International Conference on Software Engineering: Software Engineering in Practice, pp. 55-64. ACM, (2018).
Foidl, H., Felderer, M., Biffl, S.: Technical debt in data-intensive software systems. In: 45th Euromicro Conference on Software Engineering and Advanced Applications, pp. 338 –341. IEEE, (2019). https://doi.org/10.1109/SEAA.2019.00058 (Missing (foreign key) constraints)
Factor, P.: SQL Code Smells. Redgate, http://assets.red-gate.com/community/books/sql-code-smells.pdf, last accessed 2019/12/29 (Not using referential integrity constraints)
Balogh, G., Gergely, T., Beszédes, Á., Szarka, A., Fábián, Z.: Capturing expert knowledge to guide data flow and structure analysis of large corporate databases. Acta Polytechnica Hungarica 16(4), 7–26 (2019). (Isolated table)
Dintyala, P., Narechania, A., Arulraj, J.: SQLCheck: automated detection and diagnosis of SQL anti-patterns. In: 2020 ACM SIGMOD International Conference on Management of Data, pp. 2331–2345. (2020). https://doi.org/10.1145/3318464.3389754 (No foreign key)
Mistake (4): https://www.red-gate.com/simple-talk/sql/database-administration/five-simple--database-design-errors-you-should-avoid/

The list of all the queries