Query goal: | Find foreign keys where the name of the foreign key column and the corresponding primary key/unique column is different and the difference is one character. Exclude foreign key columns that refer to the key of the same table because within each named table column names must be different. Simplify writing queries that have to join data from multiple base tables. If the columns that participate in the join condition have the same name, then one can use the USING syntax. |
Notes about the query: | The query finds the foreign keys where the Levenshtein distance between the primary table column name and child table column name is one. The query uses a function from the fuzzystrmatch extension. |
Query type: | Problem detection (Each row in the result could represent a flaw in the design) |
Query reliability: | High (Few or no false-positive results) |
Query license: | MIT License |
Fixing suggestion: | Rename the key column of the primary table or the foreign key column of the child table. |
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) or (foreign_schema=target_schema and foreign_table<>target_table)) and foreign_col<>target_col and levenshtein_less_equal(foreign_col,target_col,1)=1 order by target_schema, target_table, conname; DROP EXTENSION IF EXISTS fuzzystrmatch; |
Collection name | Collection description |
---|---|
Find problems about names | A selection of queries that return information about the names of database objects. Contains all the types of queries - problem detection, software measure, and general overview. |
Find problems automatically | Queries, 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 . |
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. |
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 |
https://www.neilwithdata.com/join-using |