Fix blocking shard moves failure due to constraint failure.

DESCRIPTION:
Fix Bug #4949 where Blocking shard moves fails if there is a foreign key between partitioned distributed tables (from child to parent). This is because we try to create constraints before attaching child partitions to parent. This causes constraint failure as parent table will be empty. Fix is to reverse the order i.e. attach partitions before we create constraints.

TESTING:
Added a new test 'shard_move_constraints_blocking' inspired for existing 'shard_move_constraints' where we trigger shard move with 'block_writes' instead of 'force_logical' to add coverage for this scenario.
release-11-onder-27-july
Nitish Upreti 2022-07-24 21:21:25 -07:00 committed by GitHub
parent 5ca792aef9
commit fcdf4434c6
No known key found for this signature in database
GPG Key ID: 4AEE18F83AFDEB23
4 changed files with 633 additions and 21 deletions

View File

@ -53,6 +53,18 @@
#include "utils/rel.h"
#include "utils/syscache.h"
/* local type declarations */
/*
* ShardInterval along with to be executed
* DDL command list.
*/
typedef struct ShardCommandList
{
ShardInterval *shardInterval;
List *ddlCommandList;
} ShardCommandList;
/* local function forward declarations */
static void VerifyTablesHaveReplicaIdentity(List *colocatedTableList);
static bool RelationCanPublishAllModifications(Oid relationId);
@ -114,6 +126,8 @@ static List * CopyShardContentsCommandList(ShardInterval *shardInterval,
static List * PostLoadShardCreationCommandList(ShardInterval *shardInterval,
const char *sourceNodeName,
int32 sourceNodePort);
static ShardCommandList * CreateShardCommandList(ShardInterval *shardInterval,
List *ddlCommandList);
/* declarations for dynamic loading */
@ -1129,6 +1143,22 @@ CopyShardTablesViaLogicalReplication(List *shardIntervalList, char *sourceNodeNa
}
/*
* CreateShardCommandList creates a struct for shard interval
* along with DDL commands to be executed.
*/
static ShardCommandList *
CreateShardCommandList(ShardInterval *shardInterval, List *ddlCommandList)
{
ShardCommandList *shardCommandList = palloc0(
sizeof(ShardCommandList));
shardCommandList->shardInterval = shardInterval;
shardCommandList->ddlCommandList = ddlCommandList;
return shardCommandList;
}
/*
* CopyShardTablesViaBlockWrites copies a shard along with its co-located shards
* from a source node to target node via COPY command. While the command is in
@ -1187,10 +1217,28 @@ CopyShardTablesViaBlockWrites(List *shardIntervalList, char *sourceNodeName,
}
/*
* Once all shards are created, we can recreate relationships between shards.
*
* Iterate through the colocated shards and create the foreign constraints and
* attach child tables to their parents in a partitioning hierarchy.
* Once all shards are copied, we can recreate relationships between shards.
* Create DDL commands to Attach child tables to their parents in a partitioning hierarchy.
*/
List *shardIntervalWithDDCommandsList = NIL;
foreach_ptr(shardInterval, shardIntervalList)
{
if (PartitionTable(shardInterval->relationId))
{
char *attachPartitionCommand =
GenerateAttachShardPartitionCommand(shardInterval);
ShardCommandList *shardCommandList = CreateShardCommandList(
shardInterval,
list_make1(attachPartitionCommand));
shardIntervalWithDDCommandsList = lappend(shardIntervalWithDDCommandsList,
shardCommandList);
}
}
/*
* Iterate through the colocated shards and create DDL commamnds
* to create the foreign constraints.
*/
foreach_ptr(shardInterval, shardIntervalList)
{
@ -1201,25 +1249,25 @@ CopyShardTablesViaBlockWrites(List *shardIntervalList, char *sourceNodeName,
&shardForeignConstraintCommandList,
&referenceTableForeignConstraintList);
List *commandList = NIL;
commandList = list_concat(commandList, shardForeignConstraintCommandList);
commandList = list_concat(commandList, referenceTableForeignConstraintList);
if (PartitionTable(shardInterval->relationId))
{
char *attachPartitionCommand =
GenerateAttachShardPartitionCommand(shardInterval);
commandList = lappend(commandList, attachPartitionCommand);
ShardCommandList *shardCommandList = CreateShardCommandList(
shardInterval,
list_concat(shardForeignConstraintCommandList,
referenceTableForeignConstraintList));
shardIntervalWithDDCommandsList = lappend(shardIntervalWithDDCommandsList,
shardCommandList);
}
char *tableOwner = TableOwner(shardInterval->relationId);
/* Now execute the Partitioning & Foreign constraints creation commads. */
ShardCommandList *shardCommandList = NULL;
foreach_ptr(shardCommandList, shardIntervalWithDDCommandsList)
{
char *tableOwner = TableOwner(shardCommandList->shardInterval->relationId);
SendCommandListToWorkerOutsideTransaction(targetNodeName, targetNodePort,
tableOwner, commandList);
tableOwner,
shardCommandList->ddlCommandList);
}
MemoryContextReset(localContext);
}
MemoryContextSwitchTo(oldContext);
}

View File

@ -34,4 +34,5 @@ test: multi_alter_table_row_level_security
test: multi_alter_table_row_level_security_escape
test: stat_statements
test: shard_move_constraints
test: shard_move_constraints_blocking
test: check_mx

View File

@ -0,0 +1,362 @@
CREATE SCHEMA "blocking shard Move Fkeys Indexes";
SET search_path TO "blocking shard Move Fkeys Indexes";
SET citus.next_shard_id TO 8970000;
SET citus.next_placement_id TO 8770000;
SET citus.shard_count TO 4;
SET citus.shard_replication_factor TO 1;
-- create a non-superuser role
CREATE ROLE mx_rebalancer_blocking_role_ent WITH LOGIN;
GRANT ALL ON SCHEMA "blocking shard Move Fkeys Indexes" TO mx_rebalancer_blocking_role_ent;
-- connect with this new role
\c - mx_rebalancer_blocking_role_ent - :master_port
SET search_path TO "blocking shard Move Fkeys Indexes";
SET citus.next_shard_id TO 8970000;
SET citus.next_placement_id TO 8770000;
SET citus.shard_count TO 4;
SET citus.shard_replication_factor TO 1;
CREATE TABLE sensors(
measureid integer,
eventdatetime date,
measure_data jsonb,
PRIMARY KEY (measureid, eventdatetime, measure_data))
PARTITION BY RANGE(eventdatetime);
CREATE TABLE sensors_old PARTITION OF sensors FOR VALUES FROM ('2000-01-01') TO ('2020-01-01');
CREATE TABLE sensors_2020_01_01 PARTITION OF sensors FOR VALUES FROM ('2020-01-01') TO ('2020-02-01');
CREATE TABLE sensors_news PARTITION OF sensors FOR VALUES FROM ('2020-05-01') TO ('2025-01-01');
CREATE INDEX index_on_parent ON sensors(lower(measureid::text));
CREATE INDEX index_on_child ON sensors_2020_01_01(lower(measure_data::text));
CREATE INDEX hash_index ON sensors USING HASH((measure_data->'IsFailed'));
CREATE INDEX index_with_include ON sensors ((measure_data->'IsFailed')) INCLUDE (measure_data, eventdatetime);
CREATE STATISTICS s1 (dependencies) ON measureid, eventdatetime FROM sensors;
CREATE STATISTICS s2 (dependencies) ON measureid, eventdatetime FROM sensors_2020_01_01;
ALTER INDEX index_on_parent ALTER COLUMN 1 SET STATISTICS 1000;
ALTER INDEX index_on_child ALTER COLUMN 1 SET STATISTICS 1000;
CLUSTER sensors_2020_01_01 USING index_on_child;
SELECT create_distributed_table('sensors', 'measureid', colocate_with:='none');
create_distributed_table
---------------------------------------------------------------------
(1 row)
-- due to https://github.com/citusdata/citus/issues/5121
\c - postgres - :master_port
SET search_path TO "blocking shard Move Fkeys Indexes";
SELECT update_distributed_table_colocation('sensors_old', 'sensors');
update_distributed_table_colocation
---------------------------------------------------------------------
(1 row)
SELECT update_distributed_table_colocation('sensors_2020_01_01', 'sensors');
update_distributed_table_colocation
---------------------------------------------------------------------
(1 row)
SELECT update_distributed_table_colocation('sensors_news', 'sensors');
update_distributed_table_colocation
---------------------------------------------------------------------
(1 row)
\c - mx_rebalancer_blocking_role_ent - :master_port
SET search_path TO "blocking shard Move Fkeys Indexes";
SET citus.shard_count TO 4;
SET citus.shard_replication_factor TO 1;
SET citus.next_shard_id TO 8970016;
SET citus.next_placement_id TO 8770016;
-- create a colocated distributed tables and create foreign keys FROM/TO
-- the partitions
CREATE TABLE colocated_dist_table (measureid integer PRIMARY KEY);
SELECT create_distributed_table('colocated_dist_table', 'measureid', colocate_with:='sensors');
create_distributed_table
---------------------------------------------------------------------
(1 row)
CLUSTER colocated_dist_table USING colocated_dist_table_pkey;
CREATE TABLE colocated_partitioned_table(
measureid integer,
eventdatetime date,
PRIMARY KEY (measureid, eventdatetime))
PARTITION BY RANGE(eventdatetime);
CREATE TABLE colocated_partitioned_table_2020_01_01 PARTITION OF colocated_partitioned_table FOR VALUES FROM ('2020-01-01') TO ('2020-02-01');
SELECT create_distributed_table('colocated_partitioned_table', 'measureid', colocate_with:='sensors');
create_distributed_table
---------------------------------------------------------------------
(1 row)
CLUSTER colocated_partitioned_table_2020_01_01 USING colocated_partitioned_table_2020_01_01_pkey;
CREATE TABLE reference_table (measureid integer PRIMARY KEY);
SELECT create_reference_table('reference_table');
create_reference_table
---------------------------------------------------------------------
(1 row)
-- this table is used to make sure that index backed
-- replica identites can have clustered indexes
-- and no index statistics
CREATE TABLE index_backed_rep_identity(key int NOT NULL);
CREATE UNIQUE INDEX uqx ON index_backed_rep_identity(key);
ALTER TABLE index_backed_rep_identity REPLICA IDENTITY USING INDEX uqx;
CLUSTER index_backed_rep_identity USING uqx;
SELECT create_distributed_table('index_backed_rep_identity', 'key', colocate_with:='sensors');
create_distributed_table
---------------------------------------------------------------------
(1 row)
-- from parent to regular dist
ALTER TABLE sensors ADD CONSTRAINT fkey_from_parent_to_dist FOREIGN KEY (measureid) REFERENCES colocated_dist_table(measureid);
-- from parent to parent
ALTER TABLE sensors ADD CONSTRAINT fkey_from_parent_to_parent FOREIGN KEY (measureid, eventdatetime) REFERENCES colocated_partitioned_table(measureid, eventdatetime);
-- from parent to child
ALTER TABLE sensors ADD CONSTRAINT fkey_from_parent_to_child FOREIGN KEY (measureid, eventdatetime) REFERENCES colocated_partitioned_table_2020_01_01(measureid, eventdatetime);
-- from parent to reference table
ALTER TABLE sensors ADD CONSTRAINT fkey_from_parent_to_ref FOREIGN KEY (measureid) REFERENCES reference_table(measureid);
-- from child to regular dist
ALTER TABLE sensors_2020_01_01 ADD CONSTRAINT fkey_from_child_to_dist FOREIGN KEY (measureid) REFERENCES colocated_dist_table(measureid);
-- from child to parent
ALTER TABLE sensors_2020_01_01 ADD CONSTRAINT fkey_from_child_to_parent FOREIGN KEY (measureid,eventdatetime) REFERENCES colocated_partitioned_table(measureid,eventdatetime);
-- from child to child
ALTER TABLE sensors_2020_01_01 ADD CONSTRAINT fkey_from_child_to_child FOREIGN KEY (measureid,eventdatetime) REFERENCES colocated_partitioned_table_2020_01_01(measureid,eventdatetime);
-- from child to reference table
ALTER TABLE sensors_2020_01_01 ADD CONSTRAINT fkey_from_child_to_ref FOREIGN KEY (measureid) REFERENCES reference_table(measureid);
-- load some data
INSERT INTO reference_table SELECT i FROM generate_series(0,1000)i;
INSERT INTO colocated_dist_table SELECT i FROM generate_series(0,1000)i;
INSERT INTO colocated_partitioned_table SELECT i, '2020-01-05' FROM generate_series(0,1000)i;
INSERT INTO sensors SELECT i, '2020-01-05', '{}' FROM generate_series(0,1000)i;
\c - postgres - :worker_1_port
SET search_path TO "blocking shard Move Fkeys Indexes", public, pg_catalog;
-- show the current state of the constraints
SELECT "Constraint", "Definition" FROM table_fkeys WHERE relid='sensors_8970000'::regclass ORDER BY 1,2;
Constraint | Definition
---------------------------------------------------------------------
fkey_from_parent_to_child_8970000 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8970024(eventdatetime, measureid)
fkey_from_parent_to_dist_8970000 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8970016(measureid)
fkey_from_parent_to_parent_8970000 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8970020(eventdatetime, measureid)
fkey_from_parent_to_ref_8970000 | FOREIGN KEY (measureid) REFERENCES reference_table_8970028(measureid)
sensors_8970000_measureid_eventdatetime_fkey | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8970024(eventdatetime, measureid)
(5 rows)
SELECT "Constraint", "Definition" FROM table_fkeys WHERE relid='sensors_2020_01_01_8970008'::regclass ORDER BY 1,2;
Constraint | Definition
---------------------------------------------------------------------
fkey_from_child_to_child_8970008 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8970024(eventdatetime, measureid)
fkey_from_child_to_dist_8970008 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8970016(measureid)
fkey_from_child_to_parent_8970008 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8970020(eventdatetime, measureid)
fkey_from_child_to_ref_8970008 | FOREIGN KEY (measureid) REFERENCES reference_table_8970028(measureid)
fkey_from_parent_to_child_8970000 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8970024(eventdatetime, measureid)
fkey_from_parent_to_dist_8970000 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8970016(measureid)
fkey_from_parent_to_parent_8970000 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8970020(eventdatetime, measureid)
fkey_from_parent_to_ref_8970000 | FOREIGN KEY (measureid) REFERENCES reference_table_8970028(measureid)
sensors_2020_01_01_8970008_measureid_eventdatetime_fkey | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8970024(eventdatetime, measureid)
(9 rows)
SELECT tablename, indexdef FROM pg_indexes WHERE tablename ='sensors_8970000' ORDER BY 1,2;
tablename | indexdef
---------------------------------------------------------------------
sensors_8970000 | CREATE INDEX hash_index_8970000 ON ONLY "blocking shard Move Fkeys Indexes".sensors_8970000 USING hash (((measure_data -> 'IsFailed'::text)))
sensors_8970000 | CREATE INDEX index_on_parent_8970000 ON ONLY "blocking shard Move Fkeys Indexes".sensors_8970000 USING btree (lower((measureid)::text))
sensors_8970000 | CREATE INDEX index_with_include_8970000 ON ONLY "blocking shard Move Fkeys Indexes".sensors_8970000 USING btree (((measure_data -> 'IsFailed'::text))) INCLUDE (measure_data, eventdatetime)
sensors_8970000 | CREATE UNIQUE INDEX sensors_pkey_8970000 ON ONLY "blocking shard Move Fkeys Indexes".sensors_8970000 USING btree (measureid, eventdatetime, measure_data)
(4 rows)
SELECT tablename, indexdef FROM pg_indexes WHERE tablename ='sensors_2020_01_01_8970008' ORDER BY 1,2;
tablename | indexdef
---------------------------------------------------------------------
sensors_2020_01_01_8970008 | CREATE INDEX index_on_child_8970008 ON "blocking shard Move Fkeys Indexes".sensors_2020_01_01_8970008 USING btree (lower((measure_data)::text))
sensors_2020_01_01_8970008 | CREATE INDEX sensors_2020_01_01_expr_idx_8970008 ON "blocking shard Move Fkeys Indexes".sensors_2020_01_01_8970008 USING hash (((measure_data -> 'IsFailed'::text)))
sensors_2020_01_01_8970008 | CREATE INDEX sensors_2020_01_01_expr_measure_data_eventdatetime_idx_8970008 ON "blocking shard Move Fkeys Indexes".sensors_2020_01_01_8970008 USING btree (((measure_data -> 'IsFailed'::text))) INCLUDE (measure_data, eventdatetime)
sensors_2020_01_01_8970008 | CREATE INDEX sensors_2020_01_01_lower_idx_8970008 ON "blocking shard Move Fkeys Indexes".sensors_2020_01_01_8970008 USING btree (lower((measureid)::text))
sensors_2020_01_01_8970008 | CREATE UNIQUE INDEX sensors_2020_01_01_pkey_8970008 ON "blocking shard Move Fkeys Indexes".sensors_2020_01_01_8970008 USING btree (measureid, eventdatetime, measure_data)
(5 rows)
SELECT tablename, indexdef FROM pg_indexes WHERE tablename ='index_backed_rep_identity_8970029' ORDER BY 1,2;
tablename | indexdef
---------------------------------------------------------------------
index_backed_rep_identity_8970029 | CREATE UNIQUE INDEX uqx_8970029 ON "blocking shard Move Fkeys Indexes".index_backed_rep_identity_8970029 USING btree (key)
(1 row)
SELECT indisclustered FROM pg_index where indisclustered AND indrelid = 'index_backed_rep_identity_8970029'::regclass;
indisclustered
---------------------------------------------------------------------
t
(1 row)
SELECT stxname FROM pg_statistic_ext
WHERE stxnamespace IN (
SELECT oid
FROM pg_namespace
WHERE nspname IN ('blocking shard Move Fkeys Indexes')
)
ORDER BY stxname ASC;
stxname
---------------------------------------------------------------------
s1
s1_8970000
s1_8970002
s2
s2_8970008
s2_8970010
(6 rows)
SELECT count(*) FROM pg_index
WHERE indisclustered
and
indrelid IN
('sensors_2020_01_01_8970008'::regclass, 'colocated_dist_table_8970016'::regclass, 'colocated_partitioned_table_2020_01_01_8970024'::regclass);
count
---------------------------------------------------------------------
3
(1 row)
\c - - - :master_port
-- make sure that constrainst are moved sanely with logical replication
SELECT citus_move_shard_placement(8970000, 'localhost', :worker_1_port, 'localhost', :worker_2_port, shard_transfer_mode:='block_writes');
citus_move_shard_placement
---------------------------------------------------------------------
(1 row)
CALL citus_cleanup_orphaned_shards();
NOTICE: cleaned up 8 orphaned shards
\c - postgres - :worker_2_port
SET search_path TO "blocking shard Move Fkeys Indexes", public, pg_catalog;
SELECT "Constraint", "Definition" FROM table_fkeys WHERE relid='sensors_8970000'::regclass ORDER BY 1,2;
Constraint | Definition
---------------------------------------------------------------------
fkey_from_parent_to_child_8970000 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8970024(eventdatetime, measureid)
fkey_from_parent_to_dist_8970000 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8970016(measureid)
fkey_from_parent_to_parent_8970000 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8970020(eventdatetime, measureid)
fkey_from_parent_to_ref_8970000 | FOREIGN KEY (measureid) REFERENCES reference_table_8970028(measureid)
sensors_8970000_measureid_eventdatetime_fkey | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8970024(eventdatetime, measureid)
(5 rows)
SELECT "Constraint", "Definition" FROM table_fkeys WHERE relid='sensors_2020_01_01_8970008'::regclass ORDER BY 1,2;
Constraint | Definition
---------------------------------------------------------------------
fkey_from_child_to_child_8970008 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8970024(eventdatetime, measureid)
fkey_from_child_to_dist_8970008 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8970016(measureid)
fkey_from_child_to_parent_8970008 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8970020(eventdatetime, measureid)
fkey_from_child_to_ref_8970008 | FOREIGN KEY (measureid) REFERENCES reference_table_8970028(measureid)
fkey_from_parent_to_child_8970000 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8970024(eventdatetime, measureid)
fkey_from_parent_to_dist_8970000 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8970016(measureid)
fkey_from_parent_to_parent_8970000 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8970020(eventdatetime, measureid)
fkey_from_parent_to_ref_8970000 | FOREIGN KEY (measureid) REFERENCES reference_table_8970028(measureid)
sensors_2020_01_01_8970008_measureid_eventdatetime_fkey | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8970024(eventdatetime, measureid)
(9 rows)
SELECT tablename, indexdef FROM pg_indexes WHERE tablename ='sensors_8970000' ORDER BY 1,2;
tablename | indexdef
---------------------------------------------------------------------
sensors_8970000 | CREATE INDEX hash_index_8970000 ON ONLY "blocking shard Move Fkeys Indexes".sensors_8970000 USING hash (((measure_data -> 'IsFailed'::text)))
sensors_8970000 | CREATE INDEX index_on_parent_8970000 ON ONLY "blocking shard Move Fkeys Indexes".sensors_8970000 USING btree (lower((measureid)::text))
sensors_8970000 | CREATE INDEX index_with_include_8970000 ON ONLY "blocking shard Move Fkeys Indexes".sensors_8970000 USING btree (((measure_data -> 'IsFailed'::text))) INCLUDE (measure_data, eventdatetime)
sensors_8970000 | CREATE UNIQUE INDEX sensors_pkey_8970000 ON ONLY "blocking shard Move Fkeys Indexes".sensors_8970000 USING btree (measureid, eventdatetime, measure_data)
(4 rows)
SELECT tablename, indexdef FROM pg_indexes WHERE tablename ='sensors_2020_01_01_8970008' ORDER BY 1,2;
tablename | indexdef
---------------------------------------------------------------------
sensors_2020_01_01_8970008 | CREATE INDEX index_on_child_8970008 ON "blocking shard Move Fkeys Indexes".sensors_2020_01_01_8970008 USING btree (lower((measure_data)::text))
sensors_2020_01_01_8970008 | CREATE INDEX sensors_2020_01_01_expr_idx_8970008 ON "blocking shard Move Fkeys Indexes".sensors_2020_01_01_8970008 USING hash (((measure_data -> 'IsFailed'::text)))
sensors_2020_01_01_8970008 | CREATE INDEX sensors_2020_01_01_expr_measure_data_eventdatetime_idx_8970008 ON "blocking shard Move Fkeys Indexes".sensors_2020_01_01_8970008 USING btree (((measure_data -> 'IsFailed'::text))) INCLUDE (measure_data, eventdatetime)
sensors_2020_01_01_8970008 | CREATE INDEX sensors_2020_01_01_lower_idx_8970008 ON "blocking shard Move Fkeys Indexes".sensors_2020_01_01_8970008 USING btree (lower((measureid)::text))
sensors_2020_01_01_8970008 | CREATE UNIQUE INDEX sensors_2020_01_01_pkey_8970008 ON "blocking shard Move Fkeys Indexes".sensors_2020_01_01_8970008 USING btree (measureid, eventdatetime, measure_data)
(5 rows)
SELECT tablename, indexdef FROM pg_indexes WHERE tablename ='index_backed_rep_identity_8970029' ORDER BY 1,2;
tablename | indexdef
---------------------------------------------------------------------
index_backed_rep_identity_8970029 | CREATE UNIQUE INDEX uqx_8970029 ON "blocking shard Move Fkeys Indexes".index_backed_rep_identity_8970029 USING btree (key)
(1 row)
SELECT indisclustered FROM pg_index where indisclustered AND indrelid = 'index_backed_rep_identity_8970029'::regclass;
indisclustered
---------------------------------------------------------------------
t
(1 row)
SELECT stxname FROM pg_statistic_ext
WHERE stxnamespace IN (
SELECT oid
FROM pg_namespace
WHERE nspname IN ('blocking shard Move Fkeys Indexes')
)
ORDER BY stxname ASC;
stxname
---------------------------------------------------------------------
s1
s1_8970000
s1_8970001
s1_8970003
s2
s2_8970008
s2_8970009
s2_8970011
(8 rows)
SELECT count(*) FROM pg_index
WHERE indisclustered
and
indrelid IN
('sensors_2020_01_01_8970008'::regclass, 'colocated_dist_table_8970016'::regclass, 'colocated_partitioned_table_2020_01_01_8970024'::regclass);
count
---------------------------------------------------------------------
3
(1 row)
\c - mx_rebalancer_blocking_role_ent - :master_port
-- verify that the data is consistent
SET search_path TO "blocking shard Move Fkeys Indexes";
SELECT count(*) FROM reference_table;
count
---------------------------------------------------------------------
1001
(1 row)
SELECT count(*) FROM colocated_partitioned_table;
count
---------------------------------------------------------------------
1001
(1 row)
SELECT count(*) FROM colocated_dist_table;
count
---------------------------------------------------------------------
1001
(1 row)
SELECT count(*) FROM sensors;
count
---------------------------------------------------------------------
1001
(1 row)
-- we should be able to change/drop constraints
ALTER INDEX index_on_parent RENAME TO index_on_parent_renamed;
ALTER INDEX index_on_child RENAME TO index_on_child_renamed;
ALTER INDEX index_on_parent_renamed ALTER COLUMN 1 SET STATISTICS 200;
ALTER INDEX index_on_child_renamed ALTER COLUMN 1 SET STATISTICS 200;
DROP STATISTICS s1,s2;
DROP INDEX index_on_parent_renamed;
DROP INDEX index_on_child_renamed;
ALTER TABLE sensors DROP CONSTRAINT fkey_from_parent_to_dist;
ALTER TABLE sensors DROP CONSTRAINT fkey_from_parent_to_parent;
ALTER TABLE sensors DROP CONSTRAINT fkey_from_parent_to_child;
ALTER TABLE sensors_2020_01_01 DROP CONSTRAINT fkey_from_child_to_dist;
ALTER TABLE sensors_2020_01_01 DROP CONSTRAINT fkey_from_child_to_parent;
ALTER TABLE sensors_2020_01_01 DROP CONSTRAINT fkey_from_child_to_child;
-- cleanup
\c - postgres - :master_port
DROP SCHEMA "blocking shard Move Fkeys Indexes" CASCADE;
NOTICE: drop cascades to 5 other objects
DETAIL: drop cascades to table "blocking shard Move Fkeys Indexes".sensors
drop cascades to table "blocking shard Move Fkeys Indexes".colocated_dist_table
drop cascades to table "blocking shard Move Fkeys Indexes".colocated_partitioned_table
drop cascades to table "blocking shard Move Fkeys Indexes".reference_table
drop cascades to table "blocking shard Move Fkeys Indexes".index_backed_rep_identity

View File

@ -0,0 +1,201 @@
CREATE SCHEMA "blocking shard Move Fkeys Indexes";
SET search_path TO "blocking shard Move Fkeys Indexes";
SET citus.next_shard_id TO 8970000;
SET citus.next_placement_id TO 8770000;
SET citus.shard_count TO 4;
SET citus.shard_replication_factor TO 1;
-- create a non-superuser role
CREATE ROLE mx_rebalancer_blocking_role_ent WITH LOGIN;
GRANT ALL ON SCHEMA "blocking shard Move Fkeys Indexes" TO mx_rebalancer_blocking_role_ent;
-- connect with this new role
\c - mx_rebalancer_blocking_role_ent - :master_port
SET search_path TO "blocking shard Move Fkeys Indexes";
SET citus.next_shard_id TO 8970000;
SET citus.next_placement_id TO 8770000;
SET citus.shard_count TO 4;
SET citus.shard_replication_factor TO 1;
CREATE TABLE sensors(
measureid integer,
eventdatetime date,
measure_data jsonb,
PRIMARY KEY (measureid, eventdatetime, measure_data))
PARTITION BY RANGE(eventdatetime);
CREATE TABLE sensors_old PARTITION OF sensors FOR VALUES FROM ('2000-01-01') TO ('2020-01-01');
CREATE TABLE sensors_2020_01_01 PARTITION OF sensors FOR VALUES FROM ('2020-01-01') TO ('2020-02-01');
CREATE TABLE sensors_news PARTITION OF sensors FOR VALUES FROM ('2020-05-01') TO ('2025-01-01');
CREATE INDEX index_on_parent ON sensors(lower(measureid::text));
CREATE INDEX index_on_child ON sensors_2020_01_01(lower(measure_data::text));
CREATE INDEX hash_index ON sensors USING HASH((measure_data->'IsFailed'));
CREATE INDEX index_with_include ON sensors ((measure_data->'IsFailed')) INCLUDE (measure_data, eventdatetime);
CREATE STATISTICS s1 (dependencies) ON measureid, eventdatetime FROM sensors;
CREATE STATISTICS s2 (dependencies) ON measureid, eventdatetime FROM sensors_2020_01_01;
ALTER INDEX index_on_parent ALTER COLUMN 1 SET STATISTICS 1000;
ALTER INDEX index_on_child ALTER COLUMN 1 SET STATISTICS 1000;
CLUSTER sensors_2020_01_01 USING index_on_child;
SELECT create_distributed_table('sensors', 'measureid', colocate_with:='none');
-- due to https://github.com/citusdata/citus/issues/5121
\c - postgres - :master_port
SET search_path TO "blocking shard Move Fkeys Indexes";
SELECT update_distributed_table_colocation('sensors_old', 'sensors');
SELECT update_distributed_table_colocation('sensors_2020_01_01', 'sensors');
SELECT update_distributed_table_colocation('sensors_news', 'sensors');
\c - mx_rebalancer_blocking_role_ent - :master_port
SET search_path TO "blocking shard Move Fkeys Indexes";
SET citus.shard_count TO 4;
SET citus.shard_replication_factor TO 1;
SET citus.next_shard_id TO 8970016;
SET citus.next_placement_id TO 8770016;
-- create a colocated distributed tables and create foreign keys FROM/TO
-- the partitions
CREATE TABLE colocated_dist_table (measureid integer PRIMARY KEY);
SELECT create_distributed_table('colocated_dist_table', 'measureid', colocate_with:='sensors');
CLUSTER colocated_dist_table USING colocated_dist_table_pkey;
CREATE TABLE colocated_partitioned_table(
measureid integer,
eventdatetime date,
PRIMARY KEY (measureid, eventdatetime))
PARTITION BY RANGE(eventdatetime);
CREATE TABLE colocated_partitioned_table_2020_01_01 PARTITION OF colocated_partitioned_table FOR VALUES FROM ('2020-01-01') TO ('2020-02-01');
SELECT create_distributed_table('colocated_partitioned_table', 'measureid', colocate_with:='sensors');
CLUSTER colocated_partitioned_table_2020_01_01 USING colocated_partitioned_table_2020_01_01_pkey;
CREATE TABLE reference_table (measureid integer PRIMARY KEY);
SELECT create_reference_table('reference_table');
-- this table is used to make sure that index backed
-- replica identites can have clustered indexes
-- and no index statistics
CREATE TABLE index_backed_rep_identity(key int NOT NULL);
CREATE UNIQUE INDEX uqx ON index_backed_rep_identity(key);
ALTER TABLE index_backed_rep_identity REPLICA IDENTITY USING INDEX uqx;
CLUSTER index_backed_rep_identity USING uqx;
SELECT create_distributed_table('index_backed_rep_identity', 'key', colocate_with:='sensors');
-- from parent to regular dist
ALTER TABLE sensors ADD CONSTRAINT fkey_from_parent_to_dist FOREIGN KEY (measureid) REFERENCES colocated_dist_table(measureid);
-- from parent to parent
ALTER TABLE sensors ADD CONSTRAINT fkey_from_parent_to_parent FOREIGN KEY (measureid, eventdatetime) REFERENCES colocated_partitioned_table(measureid, eventdatetime);
-- from parent to child
ALTER TABLE sensors ADD CONSTRAINT fkey_from_parent_to_child FOREIGN KEY (measureid, eventdatetime) REFERENCES colocated_partitioned_table_2020_01_01(measureid, eventdatetime);
-- from parent to reference table
ALTER TABLE sensors ADD CONSTRAINT fkey_from_parent_to_ref FOREIGN KEY (measureid) REFERENCES reference_table(measureid);
-- from child to regular dist
ALTER TABLE sensors_2020_01_01 ADD CONSTRAINT fkey_from_child_to_dist FOREIGN KEY (measureid) REFERENCES colocated_dist_table(measureid);
-- from child to parent
ALTER TABLE sensors_2020_01_01 ADD CONSTRAINT fkey_from_child_to_parent FOREIGN KEY (measureid,eventdatetime) REFERENCES colocated_partitioned_table(measureid,eventdatetime);
-- from child to child
ALTER TABLE sensors_2020_01_01 ADD CONSTRAINT fkey_from_child_to_child FOREIGN KEY (measureid,eventdatetime) REFERENCES colocated_partitioned_table_2020_01_01(measureid,eventdatetime);
-- from child to reference table
ALTER TABLE sensors_2020_01_01 ADD CONSTRAINT fkey_from_child_to_ref FOREIGN KEY (measureid) REFERENCES reference_table(measureid);
-- load some data
INSERT INTO reference_table SELECT i FROM generate_series(0,1000)i;
INSERT INTO colocated_dist_table SELECT i FROM generate_series(0,1000)i;
INSERT INTO colocated_partitioned_table SELECT i, '2020-01-05' FROM generate_series(0,1000)i;
INSERT INTO sensors SELECT i, '2020-01-05', '{}' FROM generate_series(0,1000)i;
\c - postgres - :worker_1_port
SET search_path TO "blocking shard Move Fkeys Indexes", public, pg_catalog;
-- show the current state of the constraints
SELECT "Constraint", "Definition" FROM table_fkeys WHERE relid='sensors_8970000'::regclass ORDER BY 1,2;
SELECT "Constraint", "Definition" FROM table_fkeys WHERE relid='sensors_2020_01_01_8970008'::regclass ORDER BY 1,2;
SELECT tablename, indexdef FROM pg_indexes WHERE tablename ='sensors_8970000' ORDER BY 1,2;
SELECT tablename, indexdef FROM pg_indexes WHERE tablename ='sensors_2020_01_01_8970008' ORDER BY 1,2;
SELECT tablename, indexdef FROM pg_indexes WHERE tablename ='index_backed_rep_identity_8970029' ORDER BY 1,2;
SELECT indisclustered FROM pg_index where indisclustered AND indrelid = 'index_backed_rep_identity_8970029'::regclass;
SELECT stxname FROM pg_statistic_ext
WHERE stxnamespace IN (
SELECT oid
FROM pg_namespace
WHERE nspname IN ('blocking shard Move Fkeys Indexes')
)
ORDER BY stxname ASC;
SELECT count(*) FROM pg_index
WHERE indisclustered
and
indrelid IN
('sensors_2020_01_01_8970008'::regclass, 'colocated_dist_table_8970016'::regclass, 'colocated_partitioned_table_2020_01_01_8970024'::regclass);
\c - - - :master_port
-- make sure that constrainst are moved sanely with logical replication
SELECT citus_move_shard_placement(8970000, 'localhost', :worker_1_port, 'localhost', :worker_2_port, shard_transfer_mode:='block_writes');
CALL citus_cleanup_orphaned_shards();
\c - postgres - :worker_2_port
SET search_path TO "blocking shard Move Fkeys Indexes", public, pg_catalog;
SELECT "Constraint", "Definition" FROM table_fkeys WHERE relid='sensors_8970000'::regclass ORDER BY 1,2;
SELECT "Constraint", "Definition" FROM table_fkeys WHERE relid='sensors_2020_01_01_8970008'::regclass ORDER BY 1,2;
SELECT tablename, indexdef FROM pg_indexes WHERE tablename ='sensors_8970000' ORDER BY 1,2;
SELECT tablename, indexdef FROM pg_indexes WHERE tablename ='sensors_2020_01_01_8970008' ORDER BY 1,2;
SELECT tablename, indexdef FROM pg_indexes WHERE tablename ='index_backed_rep_identity_8970029' ORDER BY 1,2;
SELECT indisclustered FROM pg_index where indisclustered AND indrelid = 'index_backed_rep_identity_8970029'::regclass;
SELECT stxname FROM pg_statistic_ext
WHERE stxnamespace IN (
SELECT oid
FROM pg_namespace
WHERE nspname IN ('blocking shard Move Fkeys Indexes')
)
ORDER BY stxname ASC;
SELECT count(*) FROM pg_index
WHERE indisclustered
and
indrelid IN
('sensors_2020_01_01_8970008'::regclass, 'colocated_dist_table_8970016'::regclass, 'colocated_partitioned_table_2020_01_01_8970024'::regclass);
\c - mx_rebalancer_blocking_role_ent - :master_port
-- verify that the data is consistent
SET search_path TO "blocking shard Move Fkeys Indexes";
SELECT count(*) FROM reference_table;
SELECT count(*) FROM colocated_partitioned_table;
SELECT count(*) FROM colocated_dist_table;
SELECT count(*) FROM sensors;
-- we should be able to change/drop constraints
ALTER INDEX index_on_parent RENAME TO index_on_parent_renamed;
ALTER INDEX index_on_child RENAME TO index_on_child_renamed;
ALTER INDEX index_on_parent_renamed ALTER COLUMN 1 SET STATISTICS 200;
ALTER INDEX index_on_child_renamed ALTER COLUMN 1 SET STATISTICS 200;
DROP STATISTICS s1,s2;
DROP INDEX index_on_parent_renamed;
DROP INDEX index_on_child_renamed;
ALTER TABLE sensors DROP CONSTRAINT fkey_from_parent_to_dist;
ALTER TABLE sensors DROP CONSTRAINT fkey_from_parent_to_parent;
ALTER TABLE sensors DROP CONSTRAINT fkey_from_parent_to_child;
ALTER TABLE sensors_2020_01_01 DROP CONSTRAINT fkey_from_child_to_dist;
ALTER TABLE sensors_2020_01_01 DROP CONSTRAINT fkey_from_child_to_parent;
ALTER TABLE sensors_2020_01_01 DROP CONSTRAINT fkey_from_child_to_child;
-- cleanup
\c - postgres - :master_port
DROP SCHEMA "blocking shard Move Fkeys Indexes" CASCADE;