From 9ec8e627c1e4449d19f0aad0c907a2dc619978a4 Mon Sep 17 00:00:00 2001 From: Onder Kalaci Date: Fri, 12 Aug 2022 10:00:34 +0200 Subject: [PATCH] Support Sequences owned by columns before distributing tables There are 3 different ways that a sequence can be interacting with tables. (1) and (2) are already supported. This commit adds support for (3). (1) column DEFAULT nextval('seq'): The dependency is roughly like below, and ExpandCitusSupportedTypes() is responsible for finding the depending sequences. schema <--- table <--- column <---- default value ^ | |------------------ sequence <--------| (2) serial columns: Bigserial/small serial etc: The dependency is roughly like below, and ExpandCitusSupportedTypes() is responsible for finding the depending sequences. schema <--- table <--- column <---- default value ^ | | | sequence <--------| (3) Sequence OWNED BY table.column: Added support for this type of resolution in this commit. The dependency is almost like the following, and ExpandCitusSupportedTypes() is NOT responsible for finding the dependency. schema <--- table <--- column ^ | sequence --- .../commands/create_distributed_table.c | 54 +-- src/backend/distributed/commands/sequence.c | 51 +-- src/backend/distributed/commands/table.c | 8 +- src/backend/distributed/metadata/dependency.c | 14 +- .../distributed/metadata/metadata_sync.c | 33 +- src/include/distributed/metadata_sync.h | 23 +- .../regress/expected/sequencenes_owned_by.out | 314 ++++++++++++++++++ .../expected/upgrade_post_11_before.out | 10 + src/test/regress/multi_1_schedule | 1 + src/test/regress/sql/sequencenes_owned_by.sql | 161 +++++++++ .../regress/sql/upgrade_post_11_before.sql | 8 + 11 files changed, 615 insertions(+), 62 deletions(-) create mode 100644 src/test/regress/expected/sequencenes_owned_by.out create mode 100644 src/test/regress/sql/sequencenes_owned_by.sql diff --git a/src/backend/distributed/commands/create_distributed_table.c b/src/backend/distributed/commands/create_distributed_table.c index 793b0086a..0ea1fa7ca 100644 --- a/src/backend/distributed/commands/create_distributed_table.c +++ b/src/backend/distributed/commands/create_distributed_table.c @@ -118,8 +118,7 @@ static bool ShouldLocalTableBeEmpty(Oid relationId, char distributionMethod, boo viaDeprecatedAPI); static void EnsureCitusTableCanBeCreated(Oid relationOid); static void EnsureDistributedSequencesHaveOneType(Oid relationId, - List *dependentSequenceList, - List *attnumList); + List *seqInfoList); static List * GetFKeyCreationCommandsRelationInvolvedWithTableType(Oid relationId, int tableTypeFlag); static Oid DropFKeysAndUndistributeTable(Oid relationId); @@ -602,15 +601,24 @@ EnsureSequenceTypeSupported(Oid seqOid, Oid attributeTypeId, Oid ownerRelationId Oid citusTableId = InvalidOid; foreach_oid(citusTableId, citusTableIdList) { - List *attnumList = NIL; - List *dependentSequenceList = NIL; - GetDependentSequencesWithRelation(citusTableId, &attnumList, - &dependentSequenceList, 0); - AttrNumber currentAttnum = InvalidAttrNumber; - Oid currentSeqOid = InvalidOid; - forboth_int_oid(currentAttnum, attnumList, currentSeqOid, - dependentSequenceList) + List *seqInfoList = NIL; + GetDependentSequencesWithRelation(citusTableId, &seqInfoList, 0); + + SequenceInfo *seqInfo = NULL; + foreach_ptr(seqInfo, seqInfoList) { + AttrNumber currentAttnum = seqInfo->attributeNumber; + Oid currentSeqOid = seqInfo->sequenceOid; + + if (!seqInfo->isNextValDefault) + { + /* + * If a sequence is not on the nextval, we don't need any check. + * This is a dependent sequence via ALTER SEQUENCE .. OWNED BY col + */ + continue; + } + /* * If another distributed table is using the same sequence * in one of its column defaults, make sure the types of the @@ -669,11 +677,10 @@ AlterSequenceType(Oid seqOid, Oid typeOid) void EnsureRelationHasCompatibleSequenceTypes(Oid relationId) { - List *attnumList = NIL; - List *dependentSequenceList = NIL; + List *seqInfoList = NIL; - GetDependentSequencesWithRelation(relationId, &attnumList, &dependentSequenceList, 0); - EnsureDistributedSequencesHaveOneType(relationId, dependentSequenceList, attnumList); + GetDependentSequencesWithRelation(relationId, &seqInfoList, 0); + EnsureDistributedSequencesHaveOneType(relationId, seqInfoList); } @@ -683,17 +690,26 @@ EnsureRelationHasCompatibleSequenceTypes(Oid relationId) * dependentSequenceList, and then alters the sequence type if not the same with the column type. */ static void -EnsureDistributedSequencesHaveOneType(Oid relationId, List *dependentSequenceList, - List *attnumList) +EnsureDistributedSequencesHaveOneType(Oid relationId, List *seqInfoList) { - AttrNumber attnum = InvalidAttrNumber; - Oid sequenceOid = InvalidOid; - forboth_int_oid(attnum, attnumList, sequenceOid, dependentSequenceList) + SequenceInfo *seqInfo = NULL; + foreach_ptr(seqInfo, seqInfoList) { + if (!seqInfo->isNextValDefault) + { + /* + * If a sequence is not on the nextval, we don't need any check. + * This is a dependent sequence via ALTER SEQUENCE .. OWNED BY col + */ + continue; + } + /* * We should make sure that the type of the column that uses * that sequence is supported */ + Oid sequenceOid = seqInfo->sequenceOid; + AttrNumber attnum = seqInfo->attributeNumber; Oid attributeTypeId = GetAttributeTypeOid(relationId, attnum); EnsureSequenceTypeSupported(sequenceOid, attributeTypeId, relationId); diff --git a/src/backend/distributed/commands/sequence.c b/src/backend/distributed/commands/sequence.c index 99faad4a8..9352ae297 100644 --- a/src/backend/distributed/commands/sequence.c +++ b/src/backend/distributed/commands/sequence.c @@ -172,38 +172,41 @@ ExtractDefaultColumnsAndOwnedSequences(Oid relationId, List **columnNameList, attributeIndex++) { Form_pg_attribute attributeForm = TupleDescAttr(tupleDescriptor, attributeIndex); - if (attributeForm->attisdropped || !attributeForm->atthasdef) - { - /* - * If this column has already been dropped or it has no DEFAULT - * definition, skip it. - */ - continue; - } - if (attributeForm->attgenerated == ATTRIBUTE_GENERATED_STORED) + if (attributeForm->attisdropped || + attributeForm->attgenerated == ATTRIBUTE_GENERATED_STORED) { - /* skip columns with GENERATED AS ALWAYS expressions */ + /* skip dropped columns and columns with GENERATED AS ALWAYS expressions */ continue; } char *columnName = NameStr(attributeForm->attname); - *columnNameList = lappend(*columnNameList, columnName); - List *columnOwnedSequences = getOwnedSequences_internal(relationId, attributeIndex + 1, 0); - Oid ownedSequenceId = InvalidOid; - if (list_length(columnOwnedSequences) != 0) + if (attributeForm->atthasdef && list_length(columnOwnedSequences) == 0) { /* - * A column might only own one sequence. + * Even if there are no owned sequences, the code path still + * expects the columnName to be filled such that it can DROP + * DEFAULT for the existing nextval('seq') columns. */ - Assert(list_length(columnOwnedSequences) == 1); - ownedSequenceId = linitial_oid(columnOwnedSequences); + *ownedSequenceIdList = lappend_oid(*ownedSequenceIdList, InvalidOid); + *columnNameList = lappend(*columnNameList, columnName); + + continue; } - *ownedSequenceIdList = lappend_oid(*ownedSequenceIdList, ownedSequenceId); + Oid ownedSequenceId = InvalidOid; + foreach_oid(ownedSequenceId, columnOwnedSequences) + { + /* + * A column might have multiple sequences one via OWNED BY one another + * via bigserial/default nextval. + */ + *ownedSequenceIdList = lappend_oid(*ownedSequenceIdList, ownedSequenceId); + *columnNameList = lappend(*columnNameList, columnName); + } } relation_close(relation, NoLock); @@ -478,17 +481,15 @@ SequenceUsedInDistributedTable(const ObjectAddress *sequenceAddress) Oid citusTableId = InvalidOid; foreach_oid(citusTableId, citusTableIdList) { - List *attnumList = NIL; - List *dependentSequenceList = NIL; - GetDependentSequencesWithRelation(citusTableId, &attnumList, - &dependentSequenceList, 0); - Oid currentSeqOid = InvalidOid; - foreach_oid(currentSeqOid, dependentSequenceList) + List *seqInfoList = NIL; + GetDependentSequencesWithRelation(citusTableId, &seqInfoList, 0); + SequenceInfo *seqInfo = NULL; + foreach_ptr(seqInfo, seqInfoList) { /* * This sequence is used in a distributed table */ - if (currentSeqOid == sequenceAddress->objectId) + if (seqInfo->sequenceOid == sequenceAddress->objectId) { return citusTableId; } diff --git a/src/backend/distributed/commands/table.c b/src/backend/distributed/commands/table.c index f1d27aa22..bc897eec6 100644 --- a/src/backend/distributed/commands/table.c +++ b/src/backend/distributed/commands/table.c @@ -2816,11 +2816,9 @@ ErrorIfUnsupportedAlterTableStmt(AlterTableStmt *alterTableStatement) * changing the type of the column should not be allowed for now */ AttrNumber attnum = get_attnum(relationId, command->name); - List *attnumList = NIL; - List *dependentSequenceList = NIL; - GetDependentSequencesWithRelation(relationId, &attnumList, - &dependentSequenceList, attnum); - if (dependentSequenceList != NIL) + List *seqInfoList = NIL; + GetDependentSequencesWithRelation(relationId, &seqInfoList, attnum); + if (seqInfoList != NIL) { ereport(ERROR, (errmsg("cannot execute ALTER COLUMN TYPE .. command " "because the column involves a default coming " diff --git a/src/backend/distributed/metadata/dependency.c b/src/backend/distributed/metadata/dependency.c index 207398f57..6387d6ac4 100644 --- a/src/backend/distributed/metadata/dependency.c +++ b/src/backend/distributed/metadata/dependency.c @@ -1796,12 +1796,18 @@ GetViewRuleReferenceDependencyList(Oid viewId) static List * GetRelationSequenceDependencyList(Oid relationId) { - List *attnumList = NIL; - List *dependentSequenceList = NIL; + List *seqInfoList = NIL; + GetDependentSequencesWithRelation(relationId, &seqInfoList, 0); + + List *seqIdList = NIL; + SequenceInfo *seqInfo = NULL; + foreach_ptr(seqInfo, seqInfoList) + { + seqIdList = lappend_oid(seqIdList, seqInfo->sequenceOid); + } - GetDependentSequencesWithRelation(relationId, &attnumList, &dependentSequenceList, 0); List *sequenceDependencyDefList = - CreateObjectAddressDependencyDefList(RelationRelationId, dependentSequenceList); + CreateObjectAddressDependencyDefList(RelationRelationId, seqIdList); return sequenceDependencyDefList; } diff --git a/src/backend/distributed/metadata/metadata_sync.c b/src/backend/distributed/metadata/metadata_sync.c index b45a3641e..f7ab4376e 100644 --- a/src/backend/distributed/metadata/metadata_sync.c +++ b/src/backend/distributed/metadata/metadata_sync.c @@ -1580,10 +1580,10 @@ GetAttributeTypeOid(Oid relationId, AttrNumber attnum) * attribute of the relationId. */ void -GetDependentSequencesWithRelation(Oid relationId, List **attnumList, - List **dependentSequenceList, AttrNumber attnum) +GetDependentSequencesWithRelation(Oid relationId, List **seqInfoList, + AttrNumber attnum) { - Assert(*attnumList == NIL && *dependentSequenceList == NIL); + Assert(*seqInfoList == NIL); List *attrdefResult = NIL; List *attrdefAttnumResult = NIL; @@ -1620,9 +1620,26 @@ GetDependentSequencesWithRelation(Oid relationId, List **attnumList, deprec->refobjsubid != 0 && deprec->deptype == DEPENDENCY_AUTO) { + /* + * We are going to generate corresponding SequenceInfo + * in the following loop. + */ attrdefResult = lappend_oid(attrdefResult, deprec->objid); attrdefAttnumResult = lappend_int(attrdefAttnumResult, deprec->refobjsubid); } + else if (deprec->deptype == DEPENDENCY_AUTO && + deprec->refobjsubid != 0 && + deprec->classid == RelationRelationId && + get_rel_relkind(deprec->objid) == RELKIND_SEQUENCE) + { + SequenceInfo *seqInfo = (SequenceInfo *) palloc(sizeof(SequenceInfo)); + + seqInfo->sequenceOid = deprec->objid; + seqInfo->attributeNumber = deprec->refobjsubid; + seqInfo->isNextValDefault = false; + + *seqInfoList = lappend(*seqInfoList, seqInfo); + } } systable_endscan(scan); @@ -1646,9 +1663,13 @@ GetDependentSequencesWithRelation(Oid relationId, List **attnumList, if (list_length(sequencesFromAttrDef) == 1) { - *dependentSequenceList = list_concat(*dependentSequenceList, - sequencesFromAttrDef); - *attnumList = lappend_int(*attnumList, attrdefAttnum); + SequenceInfo *seqInfo = (SequenceInfo *) palloc(sizeof(SequenceInfo)); + + seqInfo->sequenceOid = linitial_oid(sequencesFromAttrDef); + seqInfo->attributeNumber = attrdefAttnum; + seqInfo->isNextValDefault = true; + + *seqInfoList = lappend(*seqInfoList, seqInfo); } } } diff --git a/src/include/distributed/metadata_sync.h b/src/include/distributed/metadata_sync.h index 8f945bafd..e539f5f61 100644 --- a/src/include/distributed/metadata_sync.h +++ b/src/include/distributed/metadata_sync.h @@ -29,6 +29,24 @@ typedef enum NODE_METADATA_SYNC_FAILED_SYNC = 2 } NodeMetadataSyncResult; +/* + * Information about dependent sequences. We do not have the + * dependent relationId as no caller needs. But, could be added + * here if needed. + */ +typedef struct SequenceInfo +{ + Oid sequenceOid; + int attributeNumber; + + /* + * true for nexval(seq) -- which also includes serials + * false when only OWNED BY col + */ + bool isNextValDefault; +} SequenceInfo; + + /* Functions declarations for metadata syncing */ extern void SyncNodeMetadataToNode(const char *nodeNameString, int32 nodePort); extern void SyncCitusTableMetadata(Oid relationId); @@ -81,9 +99,8 @@ extern List * SequenceDependencyCommandList(Oid relationId); extern List * DDLCommandsForSequence(Oid sequenceOid, char *ownerName); extern List * GetSequencesFromAttrDef(Oid attrdefOid); -extern void GetDependentSequencesWithRelation(Oid relationId, List **attnumList, - List **dependentSequenceList, AttrNumber - attnum); +extern void GetDependentSequencesWithRelation(Oid relationId, List **seqInfoList, + AttrNumber attnum); extern List * GetDependentFunctionsWithRelation(Oid relationId); extern Oid GetAttributeTypeOid(Oid relationId, AttrNumber attnum); extern void SetLocalEnableMetadataSync(bool state); diff --git a/src/test/regress/expected/sequencenes_owned_by.out b/src/test/regress/expected/sequencenes_owned_by.out new file mode 100644 index 000000000..1d9cd1136 --- /dev/null +++ b/src/test/regress/expected/sequencenes_owned_by.out @@ -0,0 +1,314 @@ +CREATE SCHEMA "sequence tests"; +SET search_path TO "sequence tests"; +CREATE SEQUENCE "sc 1"; +-- the same sequence is on nextval and owned by the same column +CREATE TABLE test(a int, b bigint default nextval ('"sc 1"')); +ALTER SEQUENCE "sc 1" OWNED BY test.b; +SELECT create_distributed_table('test','a'); + create_distributed_table +--------------------------------------------------------------------- + +(1 row) + +-- show that "sc 1" is distributed +SELECT DISTINCT result FROM run_command_on_workers($$SELECT '"sequence tests"."sc 1"'::regclass$$); + result +--------------------------------------------------------------------- + "sequence tests"."sc 1" +(1 row) + +SELECT + pg_identify_object_as_address(classid, objid, objsubid) +FROM pg_dist_object WHERE classid = 1259 AND objid = '"sequence tests"."sc 1"'::regclass; + pg_identify_object_as_address +--------------------------------------------------------------------- + (sequence,"{""sequence tests"",""sc 1""}",{}) +(1 row) + +-- this is not supported for already distributed tables, which we might relax in the future +ALTER SEQUENCE "sc 1" OWNED BY test.b; +ERROR: Altering a distributed sequence is currently not supported. +-- drop cascades into the sequence as well +DROP TABLE test CASCADE; +SELECT DISTINCT result FROM run_command_on_workers($$SELECT '"sequence tests"."sc 1"'::regclass$$); + result +--------------------------------------------------------------------- + ERROR: relation "sequence tests.sc 1" does not exist +(1 row) + +CREATE SEQUENCE "sc 1"; +-- a sequence is on nextval and owned by another column +CREATE TABLE test(a int, b bigint default nextval ('"sc 1"'), c bigint); +ALTER SEQUENCE "sc 1" OWNED BY test.c; +SELECT create_distributed_table('test','a'); + create_distributed_table +--------------------------------------------------------------------- + +(1 row) + +-- show that "sc 1" is distributed +SELECT DISTINCT result FROM run_command_on_workers($$SELECT '"sequence tests"."sc 1"'::regclass$$); + result +--------------------------------------------------------------------- + "sequence tests"."sc 1" +(1 row) + +SELECT + pg_identify_object_as_address(classid, objid, objsubid) +FROM pg_dist_object WHERE classid = 1259 AND objid = '"sequence tests"."sc 1"'::regclass; + pg_identify_object_as_address +--------------------------------------------------------------------- + (sequence,"{""sequence tests"",""sc 1""}",{}) +(1 row) + +-- drop cascades into the schema as well +DROP TABLE test CASCADE; +SELECT DISTINCT result FROM run_command_on_workers($$SELECT '"sequence tests"."sc 1"'::regclass$$); + result +--------------------------------------------------------------------- + ERROR: relation "sequence tests.sc 1" does not exist +(1 row) + +CREATE SEQUENCE "sc 1"; +CREATE SEQUENCE "sc 2"; +-- a different sequence is on nextval and owned by another column +CREATE TABLE test(a int, b bigint default nextval ('"sc 1"'), c bigint); +ALTER SEQUENCE "sc 2" OWNED BY test.c; +SELECT create_distributed_table('test','a'); + create_distributed_table +--------------------------------------------------------------------- + +(1 row) + +-- show that "sc 1" and "sc 2" are distributed +SELECT DISTINCT result FROM run_command_on_workers($$SELECT '"sequence tests"."sc 1"'::regclass::text || ',' || '"sequence tests"."sc 2"'::regclass::text; $$); + result +--------------------------------------------------------------------- + "sequence tests"."sc 1","sequence tests"."sc 2" +(1 row) + +SELECT + pg_identify_object_as_address(classid, objid, objsubid) +FROM pg_dist_object WHERE classid = 1259 AND (objid = '"sequence tests"."sc 1"'::regclass OR objid = '"sequence tests"."sc 2"'::regclass) ORDER BY 1; + pg_identify_object_as_address +--------------------------------------------------------------------- + (sequence,"{""sequence tests"",""sc 1""}",{}) + (sequence,"{""sequence tests"",""sc 2""}",{}) +(2 rows) + +-- drop cascades into the sc2 as well as it is OWNED BY +DROP TABLE test CASCADE; +SELECT DISTINCT result FROM run_command_on_workers($$SELECT '"sequence tests"."sc 2"'::regclass::text; $$); + result +--------------------------------------------------------------------- + ERROR: relation "sequence tests.sc 2" does not exist +(1 row) + +-- and, we manually drop sc1 +DROP SEQUENCE "sc 1"; +SELECT DISTINCT result FROM run_command_on_workers($$SELECT '"sequence tests"."sc 1"'::regclass::text; $$); + result +--------------------------------------------------------------------- + ERROR: relation "sequence tests.sc 1" does not exist +(1 row) + +CREATE SEQUENCE "sc 1"; +CREATE SEQUENCE "sc 2"; +-- a different sequence is on nextval, one different column owned by a sequence, and one bigserial +CREATE TABLE test(a int, b bigint default nextval ('"sc 1"'), c bigint, d bigserial); +ALTER SEQUENCE "sc 2" OWNED BY test.c; +SELECT create_distributed_table('test','a'); + create_distributed_table +--------------------------------------------------------------------- + +(1 row) + +-- show that "sc 1", "sc 2" and test_d_seq are distributed +SELECT DISTINCT result FROM run_command_on_workers($$SELECT '"sequence tests"."sc 1"'::regclass::text || ',' || '"sequence tests"."sc 2"'::regclass::text || ',' || '"sequence tests"."test_d_seq"'::regclass::text; $$); + result +--------------------------------------------------------------------- + "sequence tests"."sc 1","sequence tests"."sc 2","sequence tests".test_d_seq +(1 row) + +SELECT + pg_identify_object_as_address(classid, objid, objsubid) +FROM pg_dist_object WHERE classid = 1259 AND (objid = '"sequence tests"."sc 1"'::regclass OR objid = '"sequence tests"."sc 2"'::regclass OR objid = '"sequence tests"."test_d_seq"'::regclass) ORDER BY 1; + pg_identify_object_as_address +--------------------------------------------------------------------- + (sequence,"{""sequence tests"",""sc 1""}",{}) + (sequence,"{""sequence tests"",""sc 2""}",{}) + (sequence,"{""sequence tests"",test_d_seq}",{}) +(3 rows) + +-- drop cascades into the schema as well +DROP TABLE test CASCADE; +CREATE SEQUENCE "sc 1"; +ERROR: relation "sc 1" already exists +CREATE SEQUENCE "sc 2"; +-- a different sequence is on nextval, one column owned by a sequence and it is bigserial +CREATE TABLE test(a int, b bigint default nextval ('"sc 1"'), c bigint, d bigserial); +ALTER SEQUENCE "sc 2" OWNED BY test.d; +SELECT create_distributed_table('test','a'); + create_distributed_table +--------------------------------------------------------------------- + +(1 row) + +-- show that "sc 1" and "sc 2" are distributed +SELECT DISTINCT result FROM run_command_on_workers($$SELECT '"sequence tests"."sc 1"'::regclass::text || ',' || '"sequence tests"."sc 2"'::regclass::text || ',' || '"sequence tests"."test_d_seq"'::regclass::text; $$); + result +--------------------------------------------------------------------- + "sequence tests"."sc 1","sequence tests"."sc 2","sequence tests".test_d_seq +(1 row) + +SELECT + pg_identify_object_as_address(classid, objid, objsubid) +FROM pg_dist_object WHERE classid = 1259 AND (objid = '"sequence tests"."sc 1"'::regclass OR objid = '"sequence tests"."sc 2"'::regclass OR objid = '"sequence tests"."test_d_seq"'::regclass) ORDER BY 1; + pg_identify_object_as_address +--------------------------------------------------------------------- + (sequence,"{""sequence tests"",""sc 1""}",{}) + (sequence,"{""sequence tests"",""sc 2""}",{}) + (sequence,"{""sequence tests"",test_d_seq}",{}) +(3 rows) + +-- drop cascades into the sc2 and test_d_seq as well +DROP TABLE test CASCADE; +SELECT DISTINCT result FROM run_command_on_workers($$SELECT '"sequence tests"."sc 2"'::regclass::text $$); + result +--------------------------------------------------------------------- + ERROR: relation "sequence tests.sc 2" does not exist +(1 row) + +SELECT DISTINCT result FROM run_command_on_workers($$SELECT '"sequence tests"."test_d_seq"'::regclass::text $$); + result +--------------------------------------------------------------------- + ERROR: relation "sequence tests.test_d_seq" does not exist +(1 row) + +-- and, we manually drop sc1 +DROP SEQUENCE "sc 1"; +SELECT DISTINCT result FROM run_command_on_workers($$SELECT '"sequence tests"."sc 1"'::regclass::text; $$); + result +--------------------------------------------------------------------- + ERROR: relation "sequence tests.sc 1" does not exist +(1 row) + +CREATE SEQUENCE "sc 1"; +CREATE SEQUENCE "sc 2"; +-- a different sequence is on nextval, one column owned by multiple sequences and it is bigserial +CREATE TABLE test(a int, b bigint default nextval ('"sc 1"'), c bigint, d bigserial); +ALTER SEQUENCE "sc 1" OWNED BY test.d; +ALTER SEQUENCE "sc 2" OWNED BY test.d; +SELECT create_distributed_table('test','a'); + create_distributed_table +--------------------------------------------------------------------- + +(1 row) + +-- show that "sc 1", "sc 2" and test_d_seq are distributed +SELECT DISTINCT result FROM run_command_on_workers($$SELECT '"sequence tests"."sc 1"'::regclass::text || ',' || '"sequence tests"."sc 2"'::regclass::text || ',' || '"sequence tests"."test_d_seq"'::regclass::text; $$); + result +--------------------------------------------------------------------- + "sequence tests"."sc 1","sequence tests"."sc 2","sequence tests".test_d_seq +(1 row) + +SELECT + pg_identify_object_as_address(classid, objid, objsubid) +FROM pg_dist_object WHERE classid = 1259 AND (objid = '"sequence tests"."sc 1"'::regclass OR objid = '"sequence tests"."sc 2"'::regclass OR objid = '"sequence tests"."test_d_seq"'::regclass) ORDER BY 1; + pg_identify_object_as_address +--------------------------------------------------------------------- + (sequence,"{""sequence tests"",""sc 1""}",{}) + (sequence,"{""sequence tests"",""sc 2""}",{}) + (sequence,"{""sequence tests"",test_d_seq}",{}) +(3 rows) + +-- drop cascades into the all the sequences as well +DROP TABLE test CASCADE; +SELECT DISTINCT result FROM run_command_on_workers($$SELECT '"sequence tests"."sc 2"'::regclass::text $$); + result +--------------------------------------------------------------------- + ERROR: relation "sequence tests.sc 2" does not exist +(1 row) + +SELECT DISTINCT result FROM run_command_on_workers($$SELECT '"sequence tests"."test_d_seq"'::regclass::text $$); + result +--------------------------------------------------------------------- + ERROR: relation "sequence tests.test_d_seq" does not exist +(1 row) + +SELECT DISTINCT result FROM run_command_on_workers($$SELECT '"sequence tests"."sc 1"'::regclass::text; $$); + result +--------------------------------------------------------------------- + ERROR: relation "sequence tests.sc 1" does not exist +(1 row) + +-- Citus local tables handles sequences slightly differently, so lets have one complex example +-- which is combination of all the examples above +CREATE SEQUENCE "sc 1"; +CREATE SEQUENCE "sc 2"; +CREATE SEQUENCE "sc 3"; +CREATE TABLE date_partitioned_citus_local_table_seq( measureid bigserial, col_a bigint, col_b bigserial, eventdate date, measure_data jsonb, PRIMARY KEY (measureid, eventdate)) PARTITION BY RANGE(eventdate); +SELECT create_time_partitions('date_partitioned_citus_local_table_seq', INTERVAL '1 month', '2022-01-01', '2021-01-01'); + create_time_partitions +--------------------------------------------------------------------- + t +(1 row) + +ALTER SEQUENCE "sc 1" OWNED BY date_partitioned_citus_local_table_seq.col_a; +ALTER SEQUENCE "sc 2" OWNED BY date_partitioned_citus_local_table_seq.col_a; +ALTER SEQUENCE "sc 3" OWNED BY date_partitioned_citus_local_table_seq.col_b; +ALTER SEQUENCE "sc 2" OWNED BY date_partitioned_citus_local_table_seq.col_b; +SELECT citus_add_local_table_to_metadata('date_partitioned_citus_local_table_seq'); + citus_add_local_table_to_metadata +--------------------------------------------------------------------- + +(1 row) + +-- show that "sc 1", "sc 2" and test_d_seq are distributed +SELECT DISTINCT result FROM run_command_on_workers($$SELECT '"sequence tests"."sc 1"'::regclass::text || ',' || '"sequence tests"."sc 2"'::regclass::text || ',' || '"sequence tests"."sc 3"'::regclass::text || ',' || '"sequence tests"."date_partitioned_citus_local_table_seq_col_b_seq"'::regclass::text; $$); + result +--------------------------------------------------------------------- + "sequence tests"."sc 1","sequence tests"."sc 2","sequence tests"."sc 3","sequence tests".date_partitioned_citus_local_table_seq_col_b_seq +(1 row) + +SELECT + pg_identify_object_as_address(classid, objid, objsubid) +FROM pg_dist_object WHERE classid = 1259 AND (objid IN ('"sequence tests"."sc 1"'::regclass, '"sequence tests"."sc 2"'::regclass, '"sequence tests"."sc 3"'::regclass, '"sequence tests"."date_partitioned_citus_local_table_seq_col_b_seq"'::regclass)) ORDER BY 1; + pg_identify_object_as_address +--------------------------------------------------------------------- + (sequence,"{""sequence tests"",date_partitioned_citus_local_table_seq_col_b_seq}",{}) + (sequence,"{""sequence tests"",""sc 1""}",{}) + (sequence,"{""sequence tests"",""sc 2""}",{}) + (sequence,"{""sequence tests"",""sc 3""}",{}) +(4 rows) + +-- this is not supported for Citus local tables as well, one day we might relax +ALTER SEQUENCE "sc 2" OWNED BY date_partitioned_citus_local_table_seq.col_a; +ERROR: Altering a distributed sequence is currently not supported. +-- drop cascades to all sequneces +DROP TABLE date_partitioned_citus_local_table_seq; +SELECT DISTINCT result FROM run_command_on_workers($$SELECT '"sequence tests"."sc 1"'::regclass$$); + result +--------------------------------------------------------------------- + ERROR: relation "sequence tests.sc 1" does not exist +(1 row) + +SELECT DISTINCT result FROM run_command_on_workers($$SELECT '"sequence tests"."sc 2"'::regclass$$); + result +--------------------------------------------------------------------- + ERROR: relation "sequence tests.sc 2" does not exist +(1 row) + +SELECT DISTINCT result FROM run_command_on_workers($$SELECT '"sequence tests"."sc 3"'::regclass$$); + result +--------------------------------------------------------------------- + ERROR: relation "sequence tests.sc 3" does not exist +(1 row) + +SELECT DISTINCT result FROM run_command_on_workers($$SELECT '"sequence tests"."date_partitioned_citus_local_table_seq_col_b_seq"'::regclass$$); + result +--------------------------------------------------------------------- + ERROR: relation "sequence tests.date_partitioned_citus_local_table_seq_col_b_seq" does not exist +(1 row) + +DROP SCHEMA "sequence tests" CASCADE; diff --git a/src/test/regress/expected/upgrade_post_11_before.out b/src/test/regress/expected/upgrade_post_11_before.out index 3ae8f3d8a..05ff85578 100644 --- a/src/test/regress/expected/upgrade_post_11_before.out +++ b/src/test/regress/expected/upgrade_post_11_before.out @@ -284,3 +284,13 @@ SELECT create_distributed_table('test_propagate_collate', 'id'); (1 row) +CREATE SEQUENCE "SC1"; +CREATE SEQUENCE "unrelated_sequence"; +CREATE TABLE test(a int, b int default nextval ('"SC1"')); +ALTER SEQUENCE "unrelated_sequence" OWNED BY test.b; +SELECT create_distributed_table('test','a'); + create_distributed_table +--------------------------------------------------------------------- + +(1 row) + diff --git a/src/test/regress/multi_1_schedule b/src/test/regress/multi_1_schedule index 287205d17..433254dec 100644 --- a/src/test/regress/multi_1_schedule +++ b/src/test/regress/multi_1_schedule @@ -290,6 +290,7 @@ test: auto_undist_citus_local test: mx_regular_user test: citus_locks test: global_cancel +test: sequencenes_owned_by test: remove_coordinator # ---------- diff --git a/src/test/regress/sql/sequencenes_owned_by.sql b/src/test/regress/sql/sequencenes_owned_by.sql new file mode 100644 index 000000000..d9604f9a4 --- /dev/null +++ b/src/test/regress/sql/sequencenes_owned_by.sql @@ -0,0 +1,161 @@ +CREATE SCHEMA "sequence tests"; +SET search_path TO "sequence tests"; + +CREATE SEQUENCE "sc 1"; + +-- the same sequence is on nextval and owned by the same column +CREATE TABLE test(a int, b bigint default nextval ('"sc 1"')); +ALTER SEQUENCE "sc 1" OWNED BY test.b; +SELECT create_distributed_table('test','a'); + +-- show that "sc 1" is distributed +SELECT DISTINCT result FROM run_command_on_workers($$SELECT '"sequence tests"."sc 1"'::regclass$$); +SELECT + pg_identify_object_as_address(classid, objid, objsubid) +FROM pg_dist_object WHERE classid = 1259 AND objid = '"sequence tests"."sc 1"'::regclass; + +-- this is not supported for already distributed tables, which we might relax in the future +ALTER SEQUENCE "sc 1" OWNED BY test.b; + +-- drop cascades into the sequence as well +DROP TABLE test CASCADE; +SELECT DISTINCT result FROM run_command_on_workers($$SELECT '"sequence tests"."sc 1"'::regclass$$); + + +CREATE SEQUENCE "sc 1"; + +-- a sequence is on nextval and owned by another column +CREATE TABLE test(a int, b bigint default nextval ('"sc 1"'), c bigint); +ALTER SEQUENCE "sc 1" OWNED BY test.c; +SELECT create_distributed_table('test','a'); + +-- show that "sc 1" is distributed +SELECT DISTINCT result FROM run_command_on_workers($$SELECT '"sequence tests"."sc 1"'::regclass$$); +SELECT + pg_identify_object_as_address(classid, objid, objsubid) +FROM pg_dist_object WHERE classid = 1259 AND objid = '"sequence tests"."sc 1"'::regclass; + +-- drop cascades into the schema as well +DROP TABLE test CASCADE; +SELECT DISTINCT result FROM run_command_on_workers($$SELECT '"sequence tests"."sc 1"'::regclass$$); + +CREATE SEQUENCE "sc 1"; +CREATE SEQUENCE "sc 2"; + +-- a different sequence is on nextval and owned by another column +CREATE TABLE test(a int, b bigint default nextval ('"sc 1"'), c bigint); +ALTER SEQUENCE "sc 2" OWNED BY test.c; +SELECT create_distributed_table('test','a'); + +-- show that "sc 1" and "sc 2" are distributed +SELECT DISTINCT result FROM run_command_on_workers($$SELECT '"sequence tests"."sc 1"'::regclass::text || ',' || '"sequence tests"."sc 2"'::regclass::text; $$); +SELECT + pg_identify_object_as_address(classid, objid, objsubid) +FROM pg_dist_object WHERE classid = 1259 AND (objid = '"sequence tests"."sc 1"'::regclass OR objid = '"sequence tests"."sc 2"'::regclass) ORDER BY 1; + +-- drop cascades into the sc2 as well as it is OWNED BY +DROP TABLE test CASCADE; +SELECT DISTINCT result FROM run_command_on_workers($$SELECT '"sequence tests"."sc 2"'::regclass::text; $$); + +-- and, we manually drop sc1 +DROP SEQUENCE "sc 1"; +SELECT DISTINCT result FROM run_command_on_workers($$SELECT '"sequence tests"."sc 1"'::regclass::text; $$); + +CREATE SEQUENCE "sc 1"; +CREATE SEQUENCE "sc 2"; + +-- a different sequence is on nextval, one different column owned by a sequence, and one bigserial +CREATE TABLE test(a int, b bigint default nextval ('"sc 1"'), c bigint, d bigserial); +ALTER SEQUENCE "sc 2" OWNED BY test.c; +SELECT create_distributed_table('test','a'); + +-- show that "sc 1", "sc 2" and test_d_seq are distributed +SELECT DISTINCT result FROM run_command_on_workers($$SELECT '"sequence tests"."sc 1"'::regclass::text || ',' || '"sequence tests"."sc 2"'::regclass::text || ',' || '"sequence tests"."test_d_seq"'::regclass::text; $$); +SELECT + pg_identify_object_as_address(classid, objid, objsubid) +FROM pg_dist_object WHERE classid = 1259 AND (objid = '"sequence tests"."sc 1"'::regclass OR objid = '"sequence tests"."sc 2"'::regclass OR objid = '"sequence tests"."test_d_seq"'::regclass) ORDER BY 1; + +-- drop cascades into the schema as well +DROP TABLE test CASCADE; + + +CREATE SEQUENCE "sc 1"; +CREATE SEQUENCE "sc 2"; + +-- a different sequence is on nextval, one column owned by a sequence and it is bigserial +CREATE TABLE test(a int, b bigint default nextval ('"sc 1"'), c bigint, d bigserial); +ALTER SEQUENCE "sc 2" OWNED BY test.d; +SELECT create_distributed_table('test','a'); + +-- show that "sc 1" and "sc 2" are distributed +SELECT DISTINCT result FROM run_command_on_workers($$SELECT '"sequence tests"."sc 1"'::regclass::text || ',' || '"sequence tests"."sc 2"'::regclass::text || ',' || '"sequence tests"."test_d_seq"'::regclass::text; $$); +SELECT + pg_identify_object_as_address(classid, objid, objsubid) +FROM pg_dist_object WHERE classid = 1259 AND (objid = '"sequence tests"."sc 1"'::regclass OR objid = '"sequence tests"."sc 2"'::regclass OR objid = '"sequence tests"."test_d_seq"'::regclass) ORDER BY 1; + +-- drop cascades into the sc2 and test_d_seq as well +DROP TABLE test CASCADE; +SELECT DISTINCT result FROM run_command_on_workers($$SELECT '"sequence tests"."sc 2"'::regclass::text $$); +SELECT DISTINCT result FROM run_command_on_workers($$SELECT '"sequence tests"."test_d_seq"'::regclass::text $$); + +-- and, we manually drop sc1 +DROP SEQUENCE "sc 1"; +SELECT DISTINCT result FROM run_command_on_workers($$SELECT '"sequence tests"."sc 1"'::regclass::text; $$); + +CREATE SEQUENCE "sc 1"; +CREATE SEQUENCE "sc 2"; + +-- a different sequence is on nextval, one column owned by multiple sequences and it is bigserial +CREATE TABLE test(a int, b bigint default nextval ('"sc 1"'), c bigint, d bigserial); +ALTER SEQUENCE "sc 1" OWNED BY test.d; +ALTER SEQUENCE "sc 2" OWNED BY test.d; + +SELECT create_distributed_table('test','a'); + +-- show that "sc 1", "sc 2" and test_d_seq are distributed +SELECT DISTINCT result FROM run_command_on_workers($$SELECT '"sequence tests"."sc 1"'::regclass::text || ',' || '"sequence tests"."sc 2"'::regclass::text || ',' || '"sequence tests"."test_d_seq"'::regclass::text; $$); +SELECT + pg_identify_object_as_address(classid, objid, objsubid) +FROM pg_dist_object WHERE classid = 1259 AND (objid = '"sequence tests"."sc 1"'::regclass OR objid = '"sequence tests"."sc 2"'::regclass OR objid = '"sequence tests"."test_d_seq"'::regclass) ORDER BY 1; + +-- drop cascades into the all the sequences as well +DROP TABLE test CASCADE; +SELECT DISTINCT result FROM run_command_on_workers($$SELECT '"sequence tests"."sc 2"'::regclass::text $$); +SELECT DISTINCT result FROM run_command_on_workers($$SELECT '"sequence tests"."test_d_seq"'::regclass::text $$); +SELECT DISTINCT result FROM run_command_on_workers($$SELECT '"sequence tests"."sc 1"'::regclass::text; $$); + + +-- Citus local tables handles sequences slightly differently, so lets have one complex example +-- which is combination of all the examples above +CREATE SEQUENCE "sc 1"; +CREATE SEQUENCE "sc 2"; +CREATE SEQUENCE "sc 3"; + +CREATE TABLE date_partitioned_citus_local_table_seq( measureid bigserial, col_a bigint, col_b bigserial, eventdate date, measure_data jsonb, PRIMARY KEY (measureid, eventdate)) PARTITION BY RANGE(eventdate); +SELECT create_time_partitions('date_partitioned_citus_local_table_seq', INTERVAL '1 month', '2022-01-01', '2021-01-01'); + +ALTER SEQUENCE "sc 1" OWNED BY date_partitioned_citus_local_table_seq.col_a; +ALTER SEQUENCE "sc 2" OWNED BY date_partitioned_citus_local_table_seq.col_a; +ALTER SEQUENCE "sc 3" OWNED BY date_partitioned_citus_local_table_seq.col_b; +ALTER SEQUENCE "sc 2" OWNED BY date_partitioned_citus_local_table_seq.col_b; + +SELECT citus_add_local_table_to_metadata('date_partitioned_citus_local_table_seq'); + + +-- show that "sc 1", "sc 2" and test_d_seq are distributed +SELECT DISTINCT result FROM run_command_on_workers($$SELECT '"sequence tests"."sc 1"'::regclass::text || ',' || '"sequence tests"."sc 2"'::regclass::text || ',' || '"sequence tests"."sc 3"'::regclass::text || ',' || '"sequence tests"."date_partitioned_citus_local_table_seq_col_b_seq"'::regclass::text; $$); +SELECT + pg_identify_object_as_address(classid, objid, objsubid) +FROM pg_dist_object WHERE classid = 1259 AND (objid IN ('"sequence tests"."sc 1"'::regclass, '"sequence tests"."sc 2"'::regclass, '"sequence tests"."sc 3"'::regclass, '"sequence tests"."date_partitioned_citus_local_table_seq_col_b_seq"'::regclass)) ORDER BY 1; + +-- this is not supported for Citus local tables as well, one day we might relax +ALTER SEQUENCE "sc 2" OWNED BY date_partitioned_citus_local_table_seq.col_a; + +-- drop cascades to all sequneces +DROP TABLE date_partitioned_citus_local_table_seq; +SELECT DISTINCT result FROM run_command_on_workers($$SELECT '"sequence tests"."sc 1"'::regclass$$); +SELECT DISTINCT result FROM run_command_on_workers($$SELECT '"sequence tests"."sc 2"'::regclass$$); +SELECT DISTINCT result FROM run_command_on_workers($$SELECT '"sequence tests"."sc 3"'::regclass$$); +SELECT DISTINCT result FROM run_command_on_workers($$SELECT '"sequence tests"."date_partitioned_citus_local_table_seq_col_b_seq"'::regclass$$); + +DROP SCHEMA "sequence tests" CASCADE; diff --git a/src/test/regress/sql/upgrade_post_11_before.sql b/src/test/regress/sql/upgrade_post_11_before.sql index abd61d44d..9d17c78ac 100644 --- a/src/test/regress/sql/upgrade_post_11_before.sql +++ b/src/test/regress/sql/upgrade_post_11_before.sql @@ -243,3 +243,11 @@ SET citus.enable_ddl_propagation TO on; CREATE TABLE test_propagate_collate(id int, t2 text COLLATE german_phonebook_unpropagated); SELECT create_distributed_table('test_propagate_collate', 'id'); + + +CREATE SEQUENCE "SC1"; +CREATE SEQUENCE "unrelated_sequence"; + +CREATE TABLE test(a int, b int default nextval ('"SC1"')); +ALTER SEQUENCE "unrelated_sequence" OWNED BY test.b; +SELECT create_distributed_table('test','a');