-
Notifications
You must be signed in to change notification settings - Fork 1.1k
Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
[BACKPORT 2.12] [#9547] YSQL: alter table of parent geo-partitioned t…
…able affects select on child Summary: Failing example: ``` -- Add column to parent partitioned table. yugabyte@yugabyte=# alter table transactions add column foo varchar(30); ALTER TABLE -- Column is added to child partition in PG metadata. yugabyte@yugabyte=# \d transactions_eu; Table "public.transactions_eu" Column | Type | Collation | Nullable | Default ---------------+-----------------------------+-----------+----------+--------- user_id | integer | | not null | geo_partition | character varying | | not null | foo | character varying(30) | | | Partition of: transactions FOR VALUES IN ('EU', 'EMEA') -- Select data from child localhost:5433 yugabyte@yugabyte=# select * from transactions_eu; ERROR: Invalid argument: Invalid column number 8 ``` The above issue is happening because ALTER on parent partitioned table recursively reflects the ALTER operation on the child partitions by the PG layer. However, this does not happen on the DocDB side. This leads to mismatch in the YSQL and DocDB metadata for the child partition tables following an ALTER, resulting in failure of future DQL and DML operations. Original Diff: https://phabricator.dev.yugabyte.com/D14685 Original Commit: ff176a5 Test Plan: Jenkins: rebase: 2.12 ybd --scb --sj --java-test org.yb.pgsql.TestPgRegressPartitions Reviewers: myang Reviewed By: myang Subscribers: yql Differential Revision: https://phabricator.dev.yugabyte.com/D15820
- Loading branch information
Showing
7 changed files
with
195 additions
and
19 deletions.
There are no files selected for viewing
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
61 changes: 61 additions & 0 deletions
61
src/postgres/src/test/regress/expected/yb_partition_alter.out
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,61 @@ | ||
-- Create a partitioned hierarchy of LIST, RANGE and HASH. | ||
CREATE TABLE root_list_parent (list_part_key char, hash_part_key int, range_part_key int) PARTITION BY LIST(list_part_key); | ||
CREATE TABLE hash_parent PARTITION OF root_list_parent FOR VALUES in ('a', 'b') PARTITION BY HASH (hash_part_key); | ||
CREATE TABLE range_parent PARTITION OF hash_parent FOR VALUES WITH (modulus 1, remainder 0) PARTITION BY RANGE (range_part_key); | ||
CREATE TABLE child_partition PARTITION OF range_parent FOR VALUES FROM (1) TO (5); | ||
INSERT INTO root_list_parent VALUES ('a', 1, 2); | ||
-- Add a column to the parent table, verify that selecting data still works. | ||
ALTER TABLE root_list_parent ADD COLUMN foo VARCHAR(2); | ||
SELECT * FROM root_list_parent; | ||
list_part_key | hash_part_key | range_part_key | foo | ||
---------------+---------------+----------------+----- | ||
a | 1 | 2 | | ||
(1 row) | ||
|
||
-- Alter column type at the parent table. | ||
ALTER TABLE root_list_parent ALTER COLUMN foo TYPE VARCHAR(3); | ||
INSERT INTO root_list_parent VALUES ('a', 1, 2, 'abc'); | ||
SELECT * FROM root_list_parent ORDER BY foo; | ||
list_part_key | hash_part_key | range_part_key | foo | ||
---------------+---------------+----------------+----- | ||
a | 1 | 2 | abc | ||
a | 1 | 2 | | ||
(2 rows) | ||
|
||
-- Drop a column from the parent table, verify that selecting data still works. | ||
ALTER TABLE root_list_parent DROP COLUMN foo; | ||
SELECT * FROM root_list_parent; | ||
list_part_key | hash_part_key | range_part_key | ||
---------------+---------------+---------------- | ||
a | 1 | 2 | ||
a | 1 | 2 | ||
(2 rows) | ||
|
||
-- Retry adding a column after error. | ||
ALTER TABLE root_list_parent ADD COLUMN foo text not null; -- fails due to not null constraint | ||
ERROR: column "foo" contains null values | ||
ALTER TABLE root_list_parent ADD COLUMN foo text not null DEFAULT 'abc'; -- passes | ||
-- Rename a column belonging to the parent table. | ||
ALTER TABLE root_list_parent RENAME COLUMN list_part_key TO list_part_key_renamed; | ||
-- Note: Incorrect output here for 'foo' because of #9970. | ||
SELECT * FROM child_partition ORDER BY foo; | ||
list_part_key_renamed | hash_part_key | range_part_key | foo | ||
-----------------------+---------------+----------------+----- | ||
a | 1 | 2 | | ||
a | 1 | 2 | | ||
(2 rows) | ||
|
||
TRUNCATE root_list_parent; | ||
-- Add constraint to the parent table, verify that it reflects on the child partition. | ||
ALTER TABLE root_list_parent ADD CONSTRAINT constraint_test UNIQUE (list_part_key_renamed, hash_part_key, range_part_key, foo); | ||
INSERT INTO child_partition VALUES ('a', 1, 2), ('a', 1, 2); | ||
ERROR: duplicate key value violates unique constraint "child_partition_list_part_key_renamed_hash_part_key_range_p_key" | ||
-- Remove constraint from the parent table, verify that it reflects on the child partition. | ||
ALTER TABLE root_list_parent DROP CONSTRAINT constraint_test; | ||
INSERT INTO child_partition VALUES ('a', 1, 2), ('a', 1, 2); | ||
SELECT * FROM root_list_parent ORDER BY foo; | ||
list_part_key_renamed | hash_part_key | range_part_key | foo | ||
-----------------------+---------------+----------------+----- | ||
a | 1 | 2 | abc | ||
a | 1 | 2 | abc | ||
(2 rows) |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,38 @@ | ||
-- Create a partitioned hierarchy of LIST, RANGE and HASH. | ||
CREATE TABLE root_list_parent (list_part_key char, hash_part_key int, range_part_key int) PARTITION BY LIST(list_part_key); | ||
CREATE TABLE hash_parent PARTITION OF root_list_parent FOR VALUES in ('a', 'b') PARTITION BY HASH (hash_part_key); | ||
CREATE TABLE range_parent PARTITION OF hash_parent FOR VALUES WITH (modulus 1, remainder 0) PARTITION BY RANGE (range_part_key); | ||
CREATE TABLE child_partition PARTITION OF range_parent FOR VALUES FROM (1) TO (5); | ||
INSERT INTO root_list_parent VALUES ('a', 1, 2); | ||
|
||
-- Add a column to the parent table, verify that selecting data still works. | ||
ALTER TABLE root_list_parent ADD COLUMN foo VARCHAR(2); | ||
SELECT * FROM root_list_parent; | ||
|
||
-- Alter column type at the parent table. | ||
ALTER TABLE root_list_parent ALTER COLUMN foo TYPE VARCHAR(3); | ||
INSERT INTO root_list_parent VALUES ('a', 1, 2, 'abc'); | ||
SELECT * FROM root_list_parent ORDER BY foo; | ||
|
||
-- Drop a column from the parent table, verify that selecting data still works. | ||
ALTER TABLE root_list_parent DROP COLUMN foo; | ||
SELECT * FROM root_list_parent; | ||
|
||
-- Retry adding a column after error. | ||
ALTER TABLE root_list_parent ADD COLUMN foo text not null; -- fails due to not null constraint | ||
ALTER TABLE root_list_parent ADD COLUMN foo text not null DEFAULT 'abc'; -- passes | ||
|
||
-- Rename a column belonging to the parent table. | ||
ALTER TABLE root_list_parent RENAME COLUMN list_part_key TO list_part_key_renamed; | ||
-- Note: Incorrect output here for 'foo' because of #9970. | ||
SELECT * FROM child_partition ORDER BY foo; | ||
TRUNCATE root_list_parent; | ||
|
||
-- Add constraint to the parent table, verify that it reflects on the child partition. | ||
ALTER TABLE root_list_parent ADD CONSTRAINT constraint_test UNIQUE (list_part_key_renamed, hash_part_key, range_part_key, foo); | ||
INSERT INTO child_partition VALUES ('a', 1, 2), ('a', 1, 2); | ||
|
||
-- Remove constraint from the parent table, verify that it reflects on the child partition. | ||
ALTER TABLE root_list_parent DROP CONSTRAINT constraint_test; | ||
INSERT INTO child_partition VALUES ('a', 1, 2), ('a', 1, 2); | ||
SELECT * FROM root_list_parent ORDER BY foo; |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters