From cdd3b15ac8bcf810974d9b7e63d35bf2d4d5f9be Mon Sep 17 00:00:00 2001 From: Hadi Moshayedi Date: Thu, 14 Mar 2019 15:28:37 -0700 Subject: [PATCH] Fix distributed deadlock for ALTER TABLE ... ATTACH PARTITION. Following scenario resulted in distributed deadlock before this commit: CREATE TABLE partitioning_test(id int, time date) PARTITION BY RANGE (time); CREATE TABLE partitioning_test_2009 (LIKE partitioning_test); CREATE TABLE partitioning_test_reference(id int PRIMARY KEY, subid int); SELECT create_distributed_table('partitioning_test_2009', 'id'), create_distributed_table('partitioning_test', 'id'), create_reference_table('partitioning_test_reference'); ALTER TABLE partitioning_test ADD CONSTRAINT partitioning_reference_fkey FOREIGN KEY (id) REFERENCES partitioning_test_reference(id) ON DELETE CASCADE; ALTER TABLE partitioning_test_2009 ADD CONSTRAINT partitioning_reference_fkey_2009 FOREIGN KEY (id) REFERENCES partitioning_test_reference(id) ON DELETE CASCADE; ALTER TABLE partitioning_test ATTACH PARTITION partitioning_test_2009 FOR VALUES FROM ('2009-01-01') TO ('2010-01-01'); --- src/backend/distributed/commands/table.c | 2 +- .../regress/expected/multi_partitioning.out | 74 ++++++++++++++++++ .../regress/expected/multi_partitioning_0.out | 76 +++++++++++++++++++ src/test/regress/sql/multi_partitioning.sql | 52 +++++++++++++ 4 files changed, 203 insertions(+), 1 deletion(-) diff --git a/src/backend/distributed/commands/table.c b/src/backend/distributed/commands/table.c index a687931aa..9d74bd306 100644 --- a/src/backend/distributed/commands/table.c +++ b/src/backend/distributed/commands/table.c @@ -1198,7 +1198,7 @@ SetupExecutionModeForAlterTable(Oid relationId, AlterTableCmd *command) } } } - else if (alterTableType == AT_DetachPartition) + else if (alterTableType == AT_DetachPartition || alterTableType == AT_AttachPartition) { /* check if there are foreign constraints to reference tables */ if (HasForeignKeyToReferenceTable(relationId)) diff --git a/src/test/regress/expected/multi_partitioning.out b/src/test/regress/expected/multi_partitioning.out index 0d67da9c2..6a12b3d24 100644 --- a/src/test/regress/expected/multi_partitioning.out +++ b/src/test/regress/expected/multi_partitioning.out @@ -1882,6 +1882,80 @@ ORDER BY "schema-test_2009" | 4 (2 rows) +-- test we don't deadlock when attaching and detaching partitions from partitioned +-- tables with foreign keys +CREATE TABLE reference_table(id int PRIMARY KEY); +SELECT create_reference_table('reference_table'); + create_reference_table +------------------------ + +(1 row) + +CREATE TABLE reference_table_2(id int PRIMARY KEY); +SELECT create_reference_table('reference_table_2'); + create_reference_table +------------------------ + +(1 row) + +CREATE TABLE partitioning_test(id int, time date) PARTITION BY RANGE (time); +CREATE TABLE partitioning_test_2008 PARTITION OF partitioning_test FOR VALUES FROM ('2008-01-01') TO ('2009-01-01'); +CREATE TABLE partitioning_test_2009 (LIKE partitioning_test); +CREATE TABLE partitioning_test_2010 (LIKE partitioning_test); +CREATE TABLE partitioning_test_2011 (LIKE partitioning_test); +-- distributing partitioning_test will also distribute partitioning_test_2008 +SELECT create_distributed_table('partitioning_test', 'id'); + create_distributed_table +-------------------------- + +(1 row) + +SELECT create_distributed_table('partitioning_test_2009', 'id'); + create_distributed_table +-------------------------- + +(1 row) + +SELECT create_distributed_table('partitioning_test_2010', 'id'); + create_distributed_table +-------------------------- + +(1 row) + +SELECT create_distributed_table('partitioning_test_2011', 'id'); + create_distributed_table +-------------------------- + +(1 row) + +ALTER TABLE partitioning_test ADD CONSTRAINT partitioning_reference_fkey + FOREIGN KEY (id) REFERENCES reference_table(id) ON DELETE CASCADE; +ALTER TABLE partitioning_test_2009 ADD CONSTRAINT partitioning_reference_fkey_2009 + FOREIGN KEY (id) REFERENCES reference_table(id) ON DELETE CASCADE; +INSERT INTO partitioning_test_2010 VALUES (1, '2010-02-01'); +-- This should fail because of foreign key constraint violation +ALTER TABLE partitioning_test ATTACH PARTITION partitioning_test_2010 + FOR VALUES FROM ('2010-01-01') TO ('2011-01-01'); +ERROR: insert or update on table "partitioning_test_2010" violates foreign key constraint "partitioning_reference_fkey" +DETAIL: Key (id)=(1) is not present in table "reference_table". +-- Truncate, so attaching again won't fail +TRUNCATE partitioning_test_2010; +-- Attach a table which already has the same constraint +ALTER TABLE partitioning_test ATTACH PARTITION partitioning_test_2009 + FOR VALUES FROM ('2009-01-01') TO ('2010-01-01'); +-- Attach a table which doesn't have the constraint +ALTER TABLE partitioning_test ATTACH PARTITION partitioning_test_2010 + FOR VALUES FROM ('2010-01-01') TO ('2011-01-01'); +-- Attach a table which has a different constraint +ALTER TABLE partitioning_test ATTACH PARTITION partitioning_test_2011 + FOR VALUES FROM ('2011-01-01') TO ('2012-01-01'); +ALTER TABLE partitioning_test DETACH PARTITION partitioning_test_2008; +ALTER TABLE partitioning_test DETACH PARTITION partitioning_test_2009; +ALTER TABLE partitioning_test DETACH PARTITION partitioning_test_2010; +ALTER TABLE partitioning_test DETACH PARTITION partitioning_test_2011; +DROP TABLE partitioning_test, partitioning_test_2008, partitioning_test_2009, + partitioning_test_2010, partitioning_test_2011, + reference_table, reference_table_2; DROP SCHEMA partitioning_schema CASCADE; NOTICE: drop cascades to table "schema-test" RESET SEARCH_PATH; diff --git a/src/test/regress/expected/multi_partitioning_0.out b/src/test/regress/expected/multi_partitioning_0.out index 16ef5e7d9..c6cd13ce1 100644 --- a/src/test/regress/expected/multi_partitioning_0.out +++ b/src/test/regress/expected/multi_partitioning_0.out @@ -1806,6 +1806,82 @@ ORDER BY "schema-test_2009" | 4 (2 rows) +-- test we don't deadlock when attaching and detaching partitions from partitioned +-- tables with foreign keys +CREATE TABLE reference_table(id int PRIMARY KEY); +SELECT create_reference_table('reference_table'); + create_reference_table +------------------------ + +(1 row) + +CREATE TABLE reference_table_2(id int PRIMARY KEY); +SELECT create_reference_table('reference_table_2'); + create_reference_table +------------------------ + +(1 row) + +CREATE TABLE partitioning_test(id int, time date) PARTITION BY RANGE (time); +CREATE TABLE partitioning_test_2008 PARTITION OF partitioning_test FOR VALUES FROM ('2008-01-01') TO ('2009-01-01'); +CREATE TABLE partitioning_test_2009 (LIKE partitioning_test); +CREATE TABLE partitioning_test_2010 (LIKE partitioning_test); +CREATE TABLE partitioning_test_2011 (LIKE partitioning_test); +-- distributing partitioning_test will also distribute partitioning_test_2008 +SELECT create_distributed_table('partitioning_test', 'id'); + create_distributed_table +-------------------------- + +(1 row) + +SELECT create_distributed_table('partitioning_test_2009', 'id'); + create_distributed_table +-------------------------- + +(1 row) + +SELECT create_distributed_table('partitioning_test_2010', 'id'); + create_distributed_table +-------------------------- + +(1 row) + +SELECT create_distributed_table('partitioning_test_2011', 'id'); + create_distributed_table +-------------------------- + +(1 row) + +ALTER TABLE partitioning_test ADD CONSTRAINT partitioning_reference_fkey + FOREIGN KEY (id) REFERENCES reference_table(id) ON DELETE CASCADE; +ERROR: foreign key constraints are not supported on partitioned tables +LINE 1: ALTER TABLE partitioning_test ADD CONSTRAINT partitioning_re... + ^ +ALTER TABLE partitioning_test_2009 ADD CONSTRAINT partitioning_reference_fkey_2009 + FOREIGN KEY (id) REFERENCES reference_table(id) ON DELETE CASCADE; +INSERT INTO partitioning_test_2010 VALUES (1, '2010-02-01'); +-- This should fail because of foreign key constraint violation +ALTER TABLE partitioning_test ATTACH PARTITION partitioning_test_2010 + FOR VALUES FROM ('2010-01-01') TO ('2011-01-01'); +-- Truncate, so attaching again won't fail +TRUNCATE partitioning_test_2010; +-- Attach a table which already has the same constraint +ALTER TABLE partitioning_test ATTACH PARTITION partitioning_test_2009 + FOR VALUES FROM ('2009-01-01') TO ('2010-01-01'); +-- Attach a table which doesn't have the constraint +ALTER TABLE partitioning_test ATTACH PARTITION partitioning_test_2010 + FOR VALUES FROM ('2010-01-01') TO ('2011-01-01'); +ERROR: "partitioning_test_2010" is already a partition +-- Attach a table which has a different constraint +ALTER TABLE partitioning_test ATTACH PARTITION partitioning_test_2011 + FOR VALUES FROM ('2011-01-01') TO ('2012-01-01'); +ALTER TABLE partitioning_test DETACH PARTITION partitioning_test_2008; +ALTER TABLE partitioning_test DETACH PARTITION partitioning_test_2009; +ALTER TABLE partitioning_test DETACH PARTITION partitioning_test_2010; +ALTER TABLE partitioning_test DETACH PARTITION partitioning_test_2011; +DROP TABLE partitioning_test, partitioning_test_2008, partitioning_test_2009, + partitioning_test_2010, partitioning_test_2011, + reference_table, reference_table_2; DROP SCHEMA partitioning_schema CASCADE; NOTICE: drop cascades to table "schema-test" RESET SEARCH_PATH; diff --git a/src/test/regress/sql/multi_partitioning.sql b/src/test/regress/sql/multi_partitioning.sql index 1d3ef17ee..00d1dfa30 100644 --- a/src/test/regress/sql/multi_partitioning.sql +++ b/src/test/regress/sql/multi_partitioning.sql @@ -1127,6 +1127,58 @@ GROUP BY ORDER BY 1,2; + +-- test we don't deadlock when attaching and detaching partitions from partitioned +-- tables with foreign keys +CREATE TABLE reference_table(id int PRIMARY KEY); +SELECT create_reference_table('reference_table'); + +CREATE TABLE reference_table_2(id int PRIMARY KEY); +SELECT create_reference_table('reference_table_2'); + +CREATE TABLE partitioning_test(id int, time date) PARTITION BY RANGE (time); +CREATE TABLE partitioning_test_2008 PARTITION OF partitioning_test FOR VALUES FROM ('2008-01-01') TO ('2009-01-01'); +CREATE TABLE partitioning_test_2009 (LIKE partitioning_test); +CREATE TABLE partitioning_test_2010 (LIKE partitioning_test); +CREATE TABLE partitioning_test_2011 (LIKE partitioning_test); + +-- distributing partitioning_test will also distribute partitioning_test_2008 +SELECT create_distributed_table('partitioning_test', 'id'); +SELECT create_distributed_table('partitioning_test_2009', 'id'); +SELECT create_distributed_table('partitioning_test_2010', 'id'); +SELECT create_distributed_table('partitioning_test_2011', 'id'); + +ALTER TABLE partitioning_test ADD CONSTRAINT partitioning_reference_fkey + FOREIGN KEY (id) REFERENCES reference_table(id) ON DELETE CASCADE; +ALTER TABLE partitioning_test_2009 ADD CONSTRAINT partitioning_reference_fkey_2009 + FOREIGN KEY (id) REFERENCES reference_table(id) ON DELETE CASCADE; + +INSERT INTO partitioning_test_2010 VALUES (1, '2010-02-01'); +-- This should fail because of foreign key constraint violation +ALTER TABLE partitioning_test ATTACH PARTITION partitioning_test_2010 + FOR VALUES FROM ('2010-01-01') TO ('2011-01-01'); +-- Truncate, so attaching again won't fail +TRUNCATE partitioning_test_2010; + +-- Attach a table which already has the same constraint +ALTER TABLE partitioning_test ATTACH PARTITION partitioning_test_2009 + FOR VALUES FROM ('2009-01-01') TO ('2010-01-01'); +-- Attach a table which doesn't have the constraint +ALTER TABLE partitioning_test ATTACH PARTITION partitioning_test_2010 + FOR VALUES FROM ('2010-01-01') TO ('2011-01-01'); +-- Attach a table which has a different constraint +ALTER TABLE partitioning_test ATTACH PARTITION partitioning_test_2011 + FOR VALUES FROM ('2011-01-01') TO ('2012-01-01'); + +ALTER TABLE partitioning_test DETACH PARTITION partitioning_test_2008; +ALTER TABLE partitioning_test DETACH PARTITION partitioning_test_2009; +ALTER TABLE partitioning_test DETACH PARTITION partitioning_test_2010; +ALTER TABLE partitioning_test DETACH PARTITION partitioning_test_2011; + +DROP TABLE partitioning_test, partitioning_test_2008, partitioning_test_2009, + partitioning_test_2010, partitioning_test_2011, + reference_table, reference_table_2; + DROP SCHEMA partitioning_schema CASCADE; RESET SEARCH_PATH; DROP TABLE IF EXISTS