Query goal: | Find where a hierarchical structure is implemented in a base table by adding a foreign key that refers to a candidate key of the same table. Find only cases where the candidate key and foreign key column names are very similar (Levenshtein distance shorter than four). |
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: | Rename the foreign key column to provide better meaning. |
Data source: | system catalog only |
SQL query: | Click on query to copy it
CREATE EXTENSION IF NOT EXISTS fuzzystrmatch; with fk as (select o.conname, (select nspname from pg_namespace where oid=f.relnamespace) as foreign_schema, f.relname as foreign_table, f.oid as foreign_table_oid, unnest(o.confkey) AS foreign_col, (select nspname from pg_namespace where oid=c.relnamespace) as target_schema, c.relname as target_table, c.oid as target_table_oid, unnest(o.conkey) AS target_col from pg_constraint o inner join pg_class c on c.oid = o.conrelid inner join pg_class f on f.oid = o.confrelid where o.contype = 'f'), fk_columns as ( select fk.conname, fk.foreign_schema, fk.foreign_table, a_foreign.attname as foreign_col, fk.target_schema, fk.target_table, a_target.attname as target_col from fk inner join pg_attribute a_foreign on fk.foreign_col = a_foreign.attnum and fk.foreign_table_oid = a_foreign.attrelid and a_foreign.attisdropped = false inner join pg_attribute a_target on fk.target_col = a_target.attnum and fk.target_table_oid = a_target.attrelid and a_target.attisdropped = false) select * from fk_columns where (foreign_schema=target_schema and foreign_table=target_table) and foreign_col<>target_col and length(foreign_col)<>1 and length(target_col)<>1 and levenshtein(foreign_col,target_col) <4 order by target_schema, target_table, conname; DROP EXTENSION IF EXISTS fuzzystrmatch; |
Category name | Category description |
---|---|
Comfortability of data management | Queries of this category provide information about the means that have been used to make the use or management of database more comfortable and thus, more efficient. |
Hierarchical data | Queries of this catergory provide information about storing hierarchical data in the database. |
Naming | Queries of this category provide information about the style of naming. |
Relationships between tables | Queries 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. |
Reference |
---|
https://www.postgresql.org/docs/current/fuzzystrmatch.html |
https://en.wikipedia.org/wiki/Levenshtein_distance |