Skip to content

Commit

Permalink
Fix read_schema function for multi-column foreign key constaints (#476
Browse files Browse the repository at this point in the history
)

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
  • Loading branch information
andrew-farries authored Nov 21, 2024
1 parent 96e50f9 commit 0b08a1d
Show file tree
Hide file tree
Showing 2 changed files with 109 additions and 25 deletions.
61 changes: 36 additions & 25 deletions pkg/state/init.sql
Original file line number Diff line number Diff line change
Expand Up @@ -205,31 +205,42 @@ BEGIN
'columns', fk_details.columns,
'referencedTable', fk_details.referencedTable,
'referencedColumns', fk_details.referencedColumns,
'onDelete', fk_details.onDelete
)), '{}'::json)
FROM (SELECT fk_constraint.conname,
array_agg(fk_attr.attname ORDER BY fk_constraint.conkey::int[]) AS columns,
fk_cl.relname AS referencedTable,
array_agg(ref_attr.attname ORDER BY fk_constraint.confkey::int[]) AS referencedColumns,
CASE
WHEN fk_constraint.confdeltype = 'a' THEN 'NO ACTION'
WHEN fk_constraint.confdeltype = 'r' THEN 'RESTRICT'
WHEN fk_constraint.confdeltype = 'c' THEN 'CASCADE'
WHEN fk_constraint.confdeltype = 'd' THEN 'SET DEFAULT'
WHEN fk_constraint.confdeltype = 'n' THEN 'SET NULL'
END as onDelete
FROM pg_constraint AS fk_constraint
INNER JOIN pg_class fk_cl ON fk_constraint.confrelid = fk_cl.oid
INNER JOIN pg_attribute fk_attr
ON fk_attr.attrelid = fk_constraint.conrelid AND
fk_attr.attnum = ANY (fk_constraint.conkey)
INNER JOIN pg_attribute ref_attr
ON ref_attr.attrelid = fk_constraint.confrelid AND
ref_attr.attnum = ANY (fk_constraint.confkey)
WHERE fk_constraint.conrelid = t.oid
AND fk_constraint.contype = 'f'
GROUP BY fk_constraint.conname, fk_cl.relname,
fk_constraint.confdeltype) AS fk_details)
'onDelete', fk_details.onDelete)), '{}'::json)
FROM (SELECT
fk_info.conname as conname,
fk_info.columns as columns,
fk_info.relname as referencedTable,
array_agg(ref_attr.attname ORDER BY ref_attr.attname) AS referencedColumns,
CASE
WHEN fk_info.confdeltype = 'a' THEN 'NO ACTION'
WHEN fk_info.confdeltype = 'r' THEN 'RESTRICT'
WHEN fk_info.confdeltype = 'c' THEN 'CASCADE'
WHEN fk_info.confdeltype = 'd' THEN 'SET DEFAULT'
WHEN fk_info.confdeltype = 'n' THEN 'SET NULL'
END as onDelete
FROM (
SELECT
fk_constraint.conname,
fk_constraint.conrelid,
fk_constraint.confrelid,
fk_constraint.confkey,
fk_cl.relname,
fk_constraint.confdeltype,
array_agg(fk_attr.attname ORDER BY fk_attr.attname) AS columns
FROM pg_constraint AS fk_constraint
INNER JOIN pg_class fk_cl ON fk_constraint.confrelid = fk_cl.oid -- join the referenced table
INNER JOIN pg_attribute fk_attr ON
fk_attr.attrelid = fk_constraint.conrelid AND
fk_attr.attnum = any(fk_constraint.conkey) -- join the columns of the referencing table
WHERE fk_constraint.conrelid = t.oid
AND fk_constraint.contype = 'f'
GROUP BY fk_constraint.conrelid, fk_constraint.conname, fk_constraint.confrelid, fk_cl.relname, fk_constraint.confkey, fk_constraint.confdeltype
) AS fk_info
INNER JOIN pg_attribute ref_attr ON
ref_attr.attrelid = fk_info.confrelid AND
ref_attr.attnum = any(fk_info.confkey) -- join the columns of the referenced table
GROUP BY fk_info.conname, fk_info.conrelid, fk_info.columns, fk_info.confrelid, fk_info.confdeltype, fk_info.relname
) AS fk_details)
)), '{}'::json)
FROM pg_class AS t
INNER JOIN pg_namespace AS ns ON t.relnamespace = ns.oid
Expand Down
73 changes: 73 additions & 0 deletions pkg/state/state_test.go
Original file line number Diff line number Diff line change
Expand Up @@ -755,6 +755,79 @@ func TestReadSchema(t *testing.T) {
},
},
},
{
name: "multicolumn foreign key constraint",
createStmt: `CREATE TABLE products(
customer_id INT NOT NULL,
product_id INT NOT NULL,
PRIMARY KEY(customer_id, product_id));
CREATE TABLE orders(
customer_id INT NOT NULL,
product_id INT NOT NULL,
CONSTRAINT fk_customer_product FOREIGN KEY (customer_id, product_id) REFERENCES products (customer_id, product_id));`,
wantSchema: &schema.Schema{
Name: "public",
Tables: map[string]schema.Table{
"products": {
Name: "products",
Columns: map[string]schema.Column{
"customer_id": {
Name: "customer_id",
Type: "integer",
Nullable: false,
},
"product_id": {
Name: "product_id",
Type: "integer",
Nullable: false,
},
},
PrimaryKey: []string{"customer_id", "product_id"},
Indexes: map[string]schema.Index{
"products_pkey": {
Name: "products_pkey",
Unique: true,
Columns: []string{"customer_id", "product_id"},
Method: string(migrations.OpCreateIndexMethodBtree),
Definition: "CREATE UNIQUE INDEX products_pkey ON public.products USING btree (customer_id, product_id)",
},
},
ForeignKeys: map[string]schema.ForeignKey{},
CheckConstraints: map[string]schema.CheckConstraint{},
UniqueConstraints: map[string]schema.UniqueConstraint{},
},
"orders": {
Name: "orders",
Columns: map[string]schema.Column{
"customer_id": {
Name: "customer_id",
Type: "integer",
Nullable: false,
},
"product_id": {
Name: "product_id",
Type: "integer",
Nullable: false,
},
},
PrimaryKey: []string{},
Indexes: map[string]schema.Index{},
ForeignKeys: map[string]schema.ForeignKey{
"fk_customer_product": {
Name: "fk_customer_product",
Columns: []string{"customer_id", "product_id"},
ReferencedTable: "products",
ReferencedColumns: []string{"customer_id", "product_id"},
OnDelete: "NO ACTION",
},
},
CheckConstraints: map[string]schema.CheckConstraint{},
UniqueConstraints: map[string]schema.UniqueConstraint{},
},
},
},
},
{
name: "multi-column index",
createStmt: "CREATE TABLE public.table1 (a text, b text); CREATE INDEX idx_ab ON public.table1 (a, b);",
Expand Down

0 comments on commit 0b08a1d

Please sign in to comment.