Merge pull request #6166 from citusdata/fix_seq_ownership

Support Sequences owned by columns that are added before distributing tables
pull/6190/head
Önder Kalacı 2022-08-18 11:16:14 +02:00 committed by GitHub
commit 418b4f96d6
No known key found for this signature in database
GPG Key ID: 4AEE18F83AFDEB23
11 changed files with 615 additions and 62 deletions

View File

@ -118,8 +118,7 @@ static bool ShouldLocalTableBeEmpty(Oid relationId, char distributionMethod, boo
viaDeprecatedAPI); viaDeprecatedAPI);
static void EnsureCitusTableCanBeCreated(Oid relationOid); static void EnsureCitusTableCanBeCreated(Oid relationOid);
static void EnsureDistributedSequencesHaveOneType(Oid relationId, static void EnsureDistributedSequencesHaveOneType(Oid relationId,
List *dependentSequenceList, List *seqInfoList);
List *attnumList);
static List * GetFKeyCreationCommandsRelationInvolvedWithTableType(Oid relationId, static List * GetFKeyCreationCommandsRelationInvolvedWithTableType(Oid relationId,
int tableTypeFlag); int tableTypeFlag);
static Oid DropFKeysAndUndistributeTable(Oid relationId); static Oid DropFKeysAndUndistributeTable(Oid relationId);
@ -602,15 +601,24 @@ EnsureSequenceTypeSupported(Oid seqOid, Oid attributeTypeId, Oid ownerRelationId
Oid citusTableId = InvalidOid; Oid citusTableId = InvalidOid;
foreach_oid(citusTableId, citusTableIdList) foreach_oid(citusTableId, citusTableIdList)
{ {
List *attnumList = NIL; List *seqInfoList = NIL;
List *dependentSequenceList = NIL; GetDependentSequencesWithRelation(citusTableId, &seqInfoList, 0);
GetDependentSequencesWithRelation(citusTableId, &attnumList,
&dependentSequenceList, 0); SequenceInfo *seqInfo = NULL;
AttrNumber currentAttnum = InvalidAttrNumber; foreach_ptr(seqInfo, seqInfoList)
Oid currentSeqOid = InvalidOid;
forboth_int_oid(currentAttnum, attnumList, currentSeqOid,
dependentSequenceList)
{ {
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 * If another distributed table is using the same sequence
* in one of its column defaults, make sure the types of the * in one of its column defaults, make sure the types of the
@ -669,11 +677,10 @@ AlterSequenceType(Oid seqOid, Oid typeOid)
void void
EnsureRelationHasCompatibleSequenceTypes(Oid relationId) EnsureRelationHasCompatibleSequenceTypes(Oid relationId)
{ {
List *attnumList = NIL; List *seqInfoList = NIL;
List *dependentSequenceList = NIL;
GetDependentSequencesWithRelation(relationId, &attnumList, &dependentSequenceList, 0); GetDependentSequencesWithRelation(relationId, &seqInfoList, 0);
EnsureDistributedSequencesHaveOneType(relationId, dependentSequenceList, attnumList); 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. * dependentSequenceList, and then alters the sequence type if not the same with the column type.
*/ */
static void static void
EnsureDistributedSequencesHaveOneType(Oid relationId, List *dependentSequenceList, EnsureDistributedSequencesHaveOneType(Oid relationId, List *seqInfoList)
List *attnumList)
{ {
AttrNumber attnum = InvalidAttrNumber; SequenceInfo *seqInfo = NULL;
Oid sequenceOid = InvalidOid; foreach_ptr(seqInfo, seqInfoList)
forboth_int_oid(attnum, attnumList, sequenceOid, dependentSequenceList)
{ {
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 * We should make sure that the type of the column that uses
* that sequence is supported * that sequence is supported
*/ */
Oid sequenceOid = seqInfo->sequenceOid;
AttrNumber attnum = seqInfo->attributeNumber;
Oid attributeTypeId = GetAttributeTypeOid(relationId, attnum); Oid attributeTypeId = GetAttributeTypeOid(relationId, attnum);
EnsureSequenceTypeSupported(sequenceOid, attributeTypeId, relationId); EnsureSequenceTypeSupported(sequenceOid, attributeTypeId, relationId);

View File

@ -172,38 +172,41 @@ ExtractDefaultColumnsAndOwnedSequences(Oid relationId, List **columnNameList,
attributeIndex++) attributeIndex++)
{ {
Form_pg_attribute attributeForm = TupleDescAttr(tupleDescriptor, 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; continue;
} }
char *columnName = NameStr(attributeForm->attname); char *columnName = NameStr(attributeForm->attname);
*columnNameList = lappend(*columnNameList, columnName);
List *columnOwnedSequences = List *columnOwnedSequences =
getOwnedSequences_internal(relationId, attributeIndex + 1, 0); getOwnedSequences_internal(relationId, attributeIndex + 1, 0);
Oid ownedSequenceId = InvalidOid; if (attributeForm->atthasdef && list_length(columnOwnedSequences) == 0)
if (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); *ownedSequenceIdList = lappend_oid(*ownedSequenceIdList, InvalidOid);
ownedSequenceId = linitial_oid(columnOwnedSequences); *columnNameList = lappend(*columnNameList, columnName);
continue;
} }
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); *ownedSequenceIdList = lappend_oid(*ownedSequenceIdList, ownedSequenceId);
*columnNameList = lappend(*columnNameList, columnName);
}
} }
relation_close(relation, NoLock); relation_close(relation, NoLock);
@ -478,17 +481,15 @@ SequenceUsedInDistributedTable(const ObjectAddress *sequenceAddress)
Oid citusTableId = InvalidOid; Oid citusTableId = InvalidOid;
foreach_oid(citusTableId, citusTableIdList) foreach_oid(citusTableId, citusTableIdList)
{ {
List *attnumList = NIL; List *seqInfoList = NIL;
List *dependentSequenceList = NIL; GetDependentSequencesWithRelation(citusTableId, &seqInfoList, 0);
GetDependentSequencesWithRelation(citusTableId, &attnumList, SequenceInfo *seqInfo = NULL;
&dependentSequenceList, 0); foreach_ptr(seqInfo, seqInfoList)
Oid currentSeqOid = InvalidOid;
foreach_oid(currentSeqOid, dependentSequenceList)
{ {
/* /*
* This sequence is used in a distributed table * This sequence is used in a distributed table
*/ */
if (currentSeqOid == sequenceAddress->objectId) if (seqInfo->sequenceOid == sequenceAddress->objectId)
{ {
return citusTableId; return citusTableId;
} }

View File

@ -2816,11 +2816,9 @@ ErrorIfUnsupportedAlterTableStmt(AlterTableStmt *alterTableStatement)
* changing the type of the column should not be allowed for now * changing the type of the column should not be allowed for now
*/ */
AttrNumber attnum = get_attnum(relationId, command->name); AttrNumber attnum = get_attnum(relationId, command->name);
List *attnumList = NIL; List *seqInfoList = NIL;
List *dependentSequenceList = NIL; GetDependentSequencesWithRelation(relationId, &seqInfoList, attnum);
GetDependentSequencesWithRelation(relationId, &attnumList, if (seqInfoList != NIL)
&dependentSequenceList, attnum);
if (dependentSequenceList != NIL)
{ {
ereport(ERROR, (errmsg("cannot execute ALTER COLUMN TYPE .. command " ereport(ERROR, (errmsg("cannot execute ALTER COLUMN TYPE .. command "
"because the column involves a default coming " "because the column involves a default coming "

View File

@ -1796,12 +1796,18 @@ GetViewRuleReferenceDependencyList(Oid viewId)
static List * static List *
GetRelationSequenceDependencyList(Oid relationId) GetRelationSequenceDependencyList(Oid relationId)
{ {
List *attnumList = NIL; List *seqInfoList = NIL;
List *dependentSequenceList = 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 = List *sequenceDependencyDefList =
CreateObjectAddressDependencyDefList(RelationRelationId, dependentSequenceList); CreateObjectAddressDependencyDefList(RelationRelationId, seqIdList);
return sequenceDependencyDefList; return sequenceDependencyDefList;
} }

View File

@ -1580,10 +1580,10 @@ GetAttributeTypeOid(Oid relationId, AttrNumber attnum)
* attribute of the relationId. * attribute of the relationId.
*/ */
void void
GetDependentSequencesWithRelation(Oid relationId, List **attnumList, GetDependentSequencesWithRelation(Oid relationId, List **seqInfoList,
List **dependentSequenceList, AttrNumber attnum) AttrNumber attnum)
{ {
Assert(*attnumList == NIL && *dependentSequenceList == NIL); Assert(*seqInfoList == NIL);
List *attrdefResult = NIL; List *attrdefResult = NIL;
List *attrdefAttnumResult = NIL; List *attrdefAttnumResult = NIL;
@ -1620,9 +1620,26 @@ GetDependentSequencesWithRelation(Oid relationId, List **attnumList,
deprec->refobjsubid != 0 && deprec->refobjsubid != 0 &&
deprec->deptype == DEPENDENCY_AUTO) deprec->deptype == DEPENDENCY_AUTO)
{ {
/*
* We are going to generate corresponding SequenceInfo
* in the following loop.
*/
attrdefResult = lappend_oid(attrdefResult, deprec->objid); attrdefResult = lappend_oid(attrdefResult, deprec->objid);
attrdefAttnumResult = lappend_int(attrdefAttnumResult, deprec->refobjsubid); 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); systable_endscan(scan);
@ -1646,9 +1663,13 @@ GetDependentSequencesWithRelation(Oid relationId, List **attnumList,
if (list_length(sequencesFromAttrDef) == 1) if (list_length(sequencesFromAttrDef) == 1)
{ {
*dependentSequenceList = list_concat(*dependentSequenceList, SequenceInfo *seqInfo = (SequenceInfo *) palloc(sizeof(SequenceInfo));
sequencesFromAttrDef);
*attnumList = lappend_int(*attnumList, attrdefAttnum); seqInfo->sequenceOid = linitial_oid(sequencesFromAttrDef);
seqInfo->attributeNumber = attrdefAttnum;
seqInfo->isNextValDefault = true;
*seqInfoList = lappend(*seqInfoList, seqInfo);
} }
} }
} }

View File

@ -29,6 +29,24 @@ typedef enum
NODE_METADATA_SYNC_FAILED_SYNC = 2 NODE_METADATA_SYNC_FAILED_SYNC = 2
} NodeMetadataSyncResult; } 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 */ /* Functions declarations for metadata syncing */
extern void SyncNodeMetadataToNode(const char *nodeNameString, int32 nodePort); extern void SyncNodeMetadataToNode(const char *nodeNameString, int32 nodePort);
extern void SyncCitusTableMetadata(Oid relationId); extern void SyncCitusTableMetadata(Oid relationId);
@ -81,9 +99,8 @@ extern List * SequenceDependencyCommandList(Oid relationId);
extern List * DDLCommandsForSequence(Oid sequenceOid, char *ownerName); extern List * DDLCommandsForSequence(Oid sequenceOid, char *ownerName);
extern List * GetSequencesFromAttrDef(Oid attrdefOid); extern List * GetSequencesFromAttrDef(Oid attrdefOid);
extern void GetDependentSequencesWithRelation(Oid relationId, List **attnumList, extern void GetDependentSequencesWithRelation(Oid relationId, List **seqInfoList,
List **dependentSequenceList, AttrNumber AttrNumber attnum);
attnum);
extern List * GetDependentFunctionsWithRelation(Oid relationId); extern List * GetDependentFunctionsWithRelation(Oid relationId);
extern Oid GetAttributeTypeOid(Oid relationId, AttrNumber attnum); extern Oid GetAttributeTypeOid(Oid relationId, AttrNumber attnum);
extern void SetLocalEnableMetadataSync(bool state); extern void SetLocalEnableMetadataSync(bool state);

View File

@ -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;

View File

@ -284,3 +284,13 @@ SELECT create_distributed_table('test_propagate_collate', 'id');
(1 row) (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)

View File

@ -290,6 +290,7 @@ test: auto_undist_citus_local
test: mx_regular_user test: mx_regular_user
test: citus_locks test: citus_locks
test: global_cancel test: global_cancel
test: sequencenes_owned_by
test: remove_coordinator test: remove_coordinator
# ---------- # ----------

View File

@ -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;

View File

@ -243,3 +243,11 @@ SET citus.enable_ddl_propagation TO on;
CREATE TABLE test_propagate_collate(id int, t2 text COLLATE german_phonebook_unpropagated); CREATE TABLE test_propagate_collate(id int, t2 text COLLATE german_phonebook_unpropagated);
SELECT create_distributed_table('test_propagate_collate', 'id'); 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');