diff --git a/pkg/state/init.sql b/pkg/state/init.sql index d07400fb..99a5aad2 100644 --- a/pkg/state/init.sql +++ b/pkg/state/init.sql @@ -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 diff --git a/pkg/state/state_test.go b/pkg/state/state_test.go index 48e66738..5ff751cf 100644 --- a/pkg/state/state_test.go +++ b/pkg/state/state_test.go @@ -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);",