Skip to content

Commit 0b08a1d

Browse files
Fix read_schema function for multi-column foreign key constaints (#476)
Update the query used by `read_schema` to fetch foreign key information. This fixes the problem of `columns` and `referencedColumns` containing duplicate entries for multi-column foreign keys. For a foreign key defined like `"fk_sellers" FOREIGN KEY (sellers_name, sellers_zip) REFERENCES sellers(name, zip)` the change in behaviour is as follows: Before: ```json { ... "foreignKeys": { "fk_sellers": { "name": "fk_sellers", "columns": [ "sellers_name", "sellers_zip", "sellers_name", "sellers_zip" ], "referencedTable": "sellers", "referencedColumns": [ "name", "zip", "name", "zip" ], "onDelete": "NO ACTION" } }, } ``` After: ```json { ... "foreignKeys": { "fk_sellers": { "name": "fk_sellers", "columns": [ "sellers_name", "sellers_zip" ], "referencedTable": "sellers", "referencedColumns": [ "name", "zip" ], "onDelete": "NO ACTION" } }, } ``` The solution here is to perform grouping and array aggregation of the referencing table's columns before the join to the referenced table's columns. Fixes #475
1 parent 96e50f9 commit 0b08a1d

File tree

2 files changed

+109
-25
lines changed

2 files changed

+109
-25
lines changed

pkg/state/init.sql

Lines changed: 36 additions & 25 deletions
Original file line numberDiff line numberDiff line change
@@ -205,31 +205,42 @@ BEGIN
205205
'columns', fk_details.columns,
206206
'referencedTable', fk_details.referencedTable,
207207
'referencedColumns', fk_details.referencedColumns,
208-
'onDelete', fk_details.onDelete
209-
)), '{}'::json)
210-
FROM (SELECT fk_constraint.conname,
211-
array_agg(fk_attr.attname ORDER BY fk_constraint.conkey::int[]) AS columns,
212-
fk_cl.relname AS referencedTable,
213-
array_agg(ref_attr.attname ORDER BY fk_constraint.confkey::int[]) AS referencedColumns,
214-
CASE
215-
WHEN fk_constraint.confdeltype = 'a' THEN 'NO ACTION'
216-
WHEN fk_constraint.confdeltype = 'r' THEN 'RESTRICT'
217-
WHEN fk_constraint.confdeltype = 'c' THEN 'CASCADE'
218-
WHEN fk_constraint.confdeltype = 'd' THEN 'SET DEFAULT'
219-
WHEN fk_constraint.confdeltype = 'n' THEN 'SET NULL'
220-
END as onDelete
221-
FROM pg_constraint AS fk_constraint
222-
INNER JOIN pg_class fk_cl ON fk_constraint.confrelid = fk_cl.oid
223-
INNER JOIN pg_attribute fk_attr
224-
ON fk_attr.attrelid = fk_constraint.conrelid AND
225-
fk_attr.attnum = ANY (fk_constraint.conkey)
226-
INNER JOIN pg_attribute ref_attr
227-
ON ref_attr.attrelid = fk_constraint.confrelid AND
228-
ref_attr.attnum = ANY (fk_constraint.confkey)
229-
WHERE fk_constraint.conrelid = t.oid
230-
AND fk_constraint.contype = 'f'
231-
GROUP BY fk_constraint.conname, fk_cl.relname,
232-
fk_constraint.confdeltype) AS fk_details)
208+
'onDelete', fk_details.onDelete)), '{}'::json)
209+
FROM (SELECT
210+
fk_info.conname as conname,
211+
fk_info.columns as columns,
212+
fk_info.relname as referencedTable,
213+
array_agg(ref_attr.attname ORDER BY ref_attr.attname) AS referencedColumns,
214+
CASE
215+
WHEN fk_info.confdeltype = 'a' THEN 'NO ACTION'
216+
WHEN fk_info.confdeltype = 'r' THEN 'RESTRICT'
217+
WHEN fk_info.confdeltype = 'c' THEN 'CASCADE'
218+
WHEN fk_info.confdeltype = 'd' THEN 'SET DEFAULT'
219+
WHEN fk_info.confdeltype = 'n' THEN 'SET NULL'
220+
END as onDelete
221+
FROM (
222+
SELECT
223+
fk_constraint.conname,
224+
fk_constraint.conrelid,
225+
fk_constraint.confrelid,
226+
fk_constraint.confkey,
227+
fk_cl.relname,
228+
fk_constraint.confdeltype,
229+
array_agg(fk_attr.attname ORDER BY fk_attr.attname) AS columns
230+
FROM pg_constraint AS fk_constraint
231+
INNER JOIN pg_class fk_cl ON fk_constraint.confrelid = fk_cl.oid -- join the referenced table
232+
INNER JOIN pg_attribute fk_attr ON
233+
fk_attr.attrelid = fk_constraint.conrelid AND
234+
fk_attr.attnum = any(fk_constraint.conkey) -- join the columns of the referencing table
235+
WHERE fk_constraint.conrelid = t.oid
236+
AND fk_constraint.contype = 'f'
237+
GROUP BY fk_constraint.conrelid, fk_constraint.conname, fk_constraint.confrelid, fk_cl.relname, fk_constraint.confkey, fk_constraint.confdeltype
238+
) AS fk_info
239+
INNER JOIN pg_attribute ref_attr ON
240+
ref_attr.attrelid = fk_info.confrelid AND
241+
ref_attr.attnum = any(fk_info.confkey) -- join the columns of the referenced table
242+
GROUP BY fk_info.conname, fk_info.conrelid, fk_info.columns, fk_info.confrelid, fk_info.confdeltype, fk_info.relname
243+
) AS fk_details)
233244
)), '{}'::json)
234245
FROM pg_class AS t
235246
INNER JOIN pg_namespace AS ns ON t.relnamespace = ns.oid

pkg/state/state_test.go

Lines changed: 73 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -755,6 +755,79 @@ func TestReadSchema(t *testing.T) {
755755
},
756756
},
757757
},
758+
{
759+
name: "multicolumn foreign key constraint",
760+
createStmt: `CREATE TABLE products(
761+
customer_id INT NOT NULL,
762+
product_id INT NOT NULL,
763+
PRIMARY KEY(customer_id, product_id));
764+
765+
CREATE TABLE orders(
766+
customer_id INT NOT NULL,
767+
product_id INT NOT NULL,
768+
CONSTRAINT fk_customer_product FOREIGN KEY (customer_id, product_id) REFERENCES products (customer_id, product_id));`,
769+
wantSchema: &schema.Schema{
770+
Name: "public",
771+
Tables: map[string]schema.Table{
772+
"products": {
773+
Name: "products",
774+
Columns: map[string]schema.Column{
775+
"customer_id": {
776+
Name: "customer_id",
777+
Type: "integer",
778+
Nullable: false,
779+
},
780+
"product_id": {
781+
Name: "product_id",
782+
Type: "integer",
783+
Nullable: false,
784+
},
785+
},
786+
PrimaryKey: []string{"customer_id", "product_id"},
787+
Indexes: map[string]schema.Index{
788+
"products_pkey": {
789+
Name: "products_pkey",
790+
Unique: true,
791+
Columns: []string{"customer_id", "product_id"},
792+
Method: string(migrations.OpCreateIndexMethodBtree),
793+
Definition: "CREATE UNIQUE INDEX products_pkey ON public.products USING btree (customer_id, product_id)",
794+
},
795+
},
796+
ForeignKeys: map[string]schema.ForeignKey{},
797+
CheckConstraints: map[string]schema.CheckConstraint{},
798+
UniqueConstraints: map[string]schema.UniqueConstraint{},
799+
},
800+
"orders": {
801+
Name: "orders",
802+
Columns: map[string]schema.Column{
803+
"customer_id": {
804+
Name: "customer_id",
805+
Type: "integer",
806+
Nullable: false,
807+
},
808+
"product_id": {
809+
Name: "product_id",
810+
Type: "integer",
811+
Nullable: false,
812+
},
813+
},
814+
PrimaryKey: []string{},
815+
Indexes: map[string]schema.Index{},
816+
ForeignKeys: map[string]schema.ForeignKey{
817+
"fk_customer_product": {
818+
Name: "fk_customer_product",
819+
Columns: []string{"customer_id", "product_id"},
820+
ReferencedTable: "products",
821+
ReferencedColumns: []string{"customer_id", "product_id"},
822+
OnDelete: "NO ACTION",
823+
},
824+
},
825+
CheckConstraints: map[string]schema.CheckConstraint{},
826+
UniqueConstraints: map[string]schema.UniqueConstraint{},
827+
},
828+
},
829+
},
830+
},
758831
{
759832
name: "multi-column index",
760833
createStmt: "CREATE TABLE public.table1 (a text, b text); CREATE INDEX idx_ab ON public.table1 (a, b);",

0 commit comments

Comments
 (0)