From 5f3f1d75a35d36bd09c79d9636b5ca3787dcd5bf Mon Sep 17 00:00:00 2001 From: Onder Kalaci Date: Sun, 18 Jun 2017 20:16:18 +0300 Subject: [PATCH] Add some utility functions for partitioned tables This commit is intended to be a base for supporting declarative partitioning on distributed tables. Here we add the following utility functions and their unit tests: * Very basic functions including differnentiating partitioned tables and partitions, listing the partitions * Generating the PARTITION BY (expr) and adding this to the DDL events of partitioned tables * Ability to generate text representations of the ranges for partitions * Ability to generate the `ALTER TABLE parent_table ATTACH PARTITION partition_table FOR VALUES value_range` * Ability to apply add shard ids to the above command using `worker_apply_inter_shard_ddl_command()` * Ability to generate `ALTER TABLE parent_table DETACH PARTITION` --- .../distributed/relay/relay_event_utility.c | 42 +- .../distributed/test/partitioning_utils.c | 129 ++++++ .../distributed/utils/citus_ruleutils.c | 70 ++- .../utils/multi_partitioning_utils.c | 353 +++++++++++++++ .../distributed/utils/reference_table_utils.c | 3 +- .../distributed/multi_partitioning_utils.h | 24 + .../distributed/reference_table_utils.h | 2 + .../expected/multi_generate_ddl_commands.out | 2 +- .../expected/multi_partitioning_utils.out | 422 ++++++++++++++++++ .../expected/multi_partitioning_utils_0.out | 363 +++++++++++++++ src/test/regress/multi_schedule | 5 + .../regress/sql/multi_partitioning_utils.sql | 271 +++++++++++ 12 files changed, 1663 insertions(+), 23 deletions(-) create mode 100644 src/backend/distributed/test/partitioning_utils.c create mode 100644 src/backend/distributed/utils/multi_partitioning_utils.c create mode 100644 src/include/distributed/multi_partitioning_utils.h create mode 100644 src/test/regress/expected/multi_partitioning_utils.out create mode 100644 src/test/regress/expected/multi_partitioning_utils_0.out create mode 100644 src/test/regress/sql/multi_partitioning_utils.sql diff --git a/src/backend/distributed/relay/relay_event_utility.c b/src/backend/distributed/relay/relay_event_utility.c index bc61da45e..4a9c767af 100644 --- a/src/backend/distributed/relay/relay_event_utility.c +++ b/src/backend/distributed/relay/relay_event_utility.c @@ -437,25 +437,42 @@ RelayEventExtendNamesForInterShardCommands(Node *parseTree, uint64 leftShardId, foreach(commandCell, commandList) { AlterTableCmd *command = (AlterTableCmd *) lfirst(commandCell); + char **referencedTableName = NULL; + char **relationSchemaName = NULL; + if (command->subtype == AT_AddConstraint) { Constraint *constraint = (Constraint *) command->def; if (constraint->contype == CONSTR_FOREIGN) { - char **referencedTableName = &(constraint->pktable->relname); - char **relationSchemaName = &(constraint->pktable->schemaname); - - /* prefix with schema name if it is not added already */ - SetSchemaNameIfNotExist(relationSchemaName, rightShardSchemaName); - - /* - * We will not append shard id to referencing table name or - * constraint name. They will be handled when we drop into - * RelayEventExtendNames. - */ - AppendShardIdToName(referencedTableName, rightShardId); + referencedTableName = &(constraint->pktable->relname); + relationSchemaName = &(constraint->pktable->schemaname); } } +#if (PG_VERSION_NUM >= 100000) + else if (command->subtype == AT_AttachPartition || command->subtype == + AT_DetachPartition) + { + PartitionCmd *partitionCommand = (PartitionCmd *) command->def; + + referencedTableName = &(partitionCommand->name->relname); + relationSchemaName = &(partitionCommand->name->schemaname); + } +#endif + else + { + continue; + } + + /* prefix with schema name if it is not added already */ + SetSchemaNameIfNotExist(relationSchemaName, rightShardSchemaName); + + /* + * We will not append shard id to referencing table name or + * constraint name. They will be handled when we drop into + * RelayEventExtendNames. + */ + AppendShardIdToName(referencedTableName, rightShardId); } /* drop into RelayEventExtendNames for non-inter table commands */ @@ -604,7 +621,6 @@ AppendShardIdToName(char **name, uint64 shardId) { snprintf(extendedName, NAMEDATALEN, "%s%s", (*name), shardIdAndSeparator); } - /* * Otherwise, we need to truncate the name further to accommodate * a sufficient hash value. The resulting name will avoid collision diff --git a/src/backend/distributed/test/partitioning_utils.c b/src/backend/distributed/test/partitioning_utils.c new file mode 100644 index 000000000..ca038e93a --- /dev/null +++ b/src/backend/distributed/test/partitioning_utils.c @@ -0,0 +1,129 @@ +/*------------------------------------------------------------------------- + * + * test/src/partitioning_utils.c + * + * This file contains functions to test partitioning utility functions + * implemented in Citus. + * + * Copyright (c) 2017, Citus Data, Inc. + * + *------------------------------------------------------------------------- + */ +#include "postgres.h" +#include "fmgr.h" + +#include "catalog/pg_type.h" +#include "distributed/listutils.h" +#include "distributed/multi_partitioning_utils.h" +#include "distributed/reference_table_utils.h" +#include "lib/stringinfo.h" +#include "utils/builtins.h" +#include "utils/lsyscache.h" + + +PG_FUNCTION_INFO_V1(generate_alter_table_detach_partition_command); +PG_FUNCTION_INFO_V1(generate_alter_table_attach_partition_command); +PG_FUNCTION_INFO_V1(generate_partition_information); +PG_FUNCTION_INFO_V1(print_partitions); +PG_FUNCTION_INFO_V1(table_inherits); +PG_FUNCTION_INFO_V1(table_inherited); + + +/* + * Just a wrapper around GenereateDetachPartitionCommand(). + */ +Datum +generate_alter_table_detach_partition_command(PG_FUNCTION_ARGS) +{ + char *command = ""; + +#if (PG_VERSION_NUM >= 100000) + command = GenerateDetachPartitionCommand(PG_GETARG_OID(0)); +#endif + + PG_RETURN_TEXT_P(cstring_to_text(command)); +} + + +/* + * Just a wrapper around GenerateAlterTableAttachPartitionCommand(). + */ +Datum +generate_alter_table_attach_partition_command(PG_FUNCTION_ARGS) +{ + char *command = ""; + +#if (PG_VERSION_NUM >= 100000) + command = GenerateAlterTableAttachPartitionCommand(PG_GETARG_OID(0)); +#endif + + PG_RETURN_TEXT_P(cstring_to_text(command)); +} + + +/* + * Just a wrapper around GenereatePartitioningInformation(). + */ +Datum +generate_partition_information(PG_FUNCTION_ARGS) +{ + char *command = ""; + +#if (PG_VERSION_NUM >= 100000) + command = GeneratePartitioningInformation(PG_GETARG_OID(0)); +#endif + + PG_RETURN_TEXT_P(cstring_to_text(command)); +} + + +/* + * Just a wrapper around PartitionList() with human readable table name outpus. + */ +Datum +print_partitions(PG_FUNCTION_ARGS) +{ + StringInfo resultRelationNames = makeStringInfo(); + +#if (PG_VERSION_NUM >= 100000) + List *partitionList = PartitionList(PG_GETARG_OID(0)); + ListCell *partitionOidCell = NULL; + + partitionList = SortList(partitionList, CompareOids); + + foreach(partitionOidCell, partitionList) + { + Oid partitionOid = lfirst_oid(partitionOidCell); + + /* at least one table is already added, add comma */ + if (resultRelationNames->len > 0) + { + appendStringInfoString(resultRelationNames, ","); + } + + appendStringInfoString(resultRelationNames, get_rel_name(partitionOid)); + } +#endif + + PG_RETURN_TEXT_P(cstring_to_text(resultRelationNames->data)); +} + + +/* + * Just a wrapper around IsChildTable() + */ +Datum +table_inherits(PG_FUNCTION_ARGS) +{ + return IsChildTable(PG_GETARG_OID(0)); +} + + +/* + * Just a wrapper around IsParentTable() + */ +Datum +table_inherited(PG_FUNCTION_ARGS) +{ + return IsParentTable(PG_GETARG_OID(0)); +} diff --git a/src/backend/distributed/utils/citus_ruleutils.c b/src/backend/distributed/utils/citus_ruleutils.c index c1e2fd05d..a543669e6 100644 --- a/src/backend/distributed/utils/citus_ruleutils.c +++ b/src/backend/distributed/utils/citus_ruleutils.c @@ -34,6 +34,7 @@ #include "commands/defrem.h" #include "commands/extension.h" #include "distributed/citus_ruleutils.h" +#include "distributed/multi_partitioning_utils.h" #include "distributed/relay_utility.h" #include "foreign/foreign.h" #include "lib/stringinfo.h" @@ -58,6 +59,7 @@ static void AppendOptionListToString(StringInfo stringData, List *options); +static bool SupportedRelationKind(Relation relation); static const char * convert_aclright_to_string(int aclright); @@ -289,6 +291,7 @@ pg_get_tableschemadef_string(Oid tableRelationId, bool includeSequenceDefaults) AttrNumber constraintIndex = 0; AttrNumber constraintCount = 0; StringInfoData buffer = { NULL, 0, 0, 0 }; + bool supportedRelationKind = false; /* * Instead of retrieving values from system catalogs as other functions in @@ -301,15 +304,22 @@ pg_get_tableschemadef_string(Oid tableRelationId, bool includeSequenceDefaults) relation = relation_open(tableRelationId, AccessShareLock); relationName = generate_relation_name(tableRelationId, NIL); - relationKind = relation->rd_rel->relkind; - if (relationKind != RELKIND_RELATION && relationKind != RELKIND_FOREIGN_TABLE) + supportedRelationKind = SupportedRelationKind(relation); + if (!supportedRelationKind) { ereport(ERROR, (errcode(ERRCODE_WRONG_OBJECT_TYPE), - errmsg("%s is not a regular or foreign table", relationName))); + errmsg("%s is not a regular, foreign, or partitioned table", + relationName))); } initStringInfo(&buffer); + + relationKind = relation->rd_rel->relkind; +#if (PG_VERSION_NUM >= 100000) + if (relationKind == RELKIND_RELATION || relationKind == RELKIND_PARTITIONED_TABLE) +#else if (relationKind == RELKIND_RELATION) +#endif { appendStringInfoString(&buffer, "CREATE "); @@ -337,7 +347,15 @@ pg_get_tableschemadef_string(Oid tableRelationId, bool includeSequenceDefaults) { Form_pg_attribute attributeForm = tupleDescriptor->attrs[attributeIndex]; - if (!attributeForm->attisdropped && attributeForm->attinhcount == 0) + /* + * We disregard the inherited attributes (i.e., attinhcount > 0) here. The + * reasoning behind this is that Citus implements declarative partitioning + * by creating the partitions first and then sending + * "ALTER TABLE parent_table ATTACH PARTITION .." command. This may not play + * well with regular inhereted tables, which isn't a big concern from Citus' + * perspective. + */ + if (!attributeForm->attisdropped) { const char *attributeName = NULL; const char *attributeTypeName = NULL; @@ -459,13 +477,42 @@ pg_get_tableschemadef_string(Oid tableRelationId, bool includeSequenceDefaults) appendStringInfo(&buffer, " SERVER %s", quote_identifier(serverName)); AppendOptionListToString(&buffer, foreignTable->options); } - +#if (PG_VERSION_NUM >= 100000) + else if (relationKind == RELKIND_PARTITIONED_TABLE) + { + char *partitioningInformation = GeneratePartitioningInformation(tableRelationId); + appendStringInfo(&buffer, " PARTITION BY %s ", partitioningInformation); + } +#endif relation_close(relation, AccessShareLock); return (buffer.data); } +/* + * SupportedRelationKind returns true if the given relation is supported as a + * distributed relation. + */ +static bool +SupportedRelationKind(Relation relation) +{ + char relationKind = relation->rd_rel->relkind; + bool supportedRelationKind = (relationKind == RELKIND_RELATION || relationKind == + RELKIND_FOREIGN_TABLE); +#if (PG_VERSION_NUM >= 100000) + supportedRelationKind = supportedRelationKind || relationKind == + RELKIND_PARTITIONED_TABLE; +#endif + + /* Citus doesn't support bare inhereted tables (i.e., not a partition or partitioned table) */ + supportedRelationKind = supportedRelationKind && !(IsChildTable(relation->rd_id) || + IsParentTable(relation->rd_id)); + + return supportedRelationKind; +} + + /* * pg_get_tablecolumnoptionsdef_string returns column storage type and column * statistics definitions for given table, _if_ these definitions differ from @@ -484,6 +531,7 @@ pg_get_tablecolumnoptionsdef_string(Oid tableRelationId) ListCell *columnOptionCell = NULL; bool firstOptionPrinted = false; StringInfoData buffer = { NULL, 0, 0, 0 }; + bool supportedRelationKind = false; /* * Instead of retrieving values from system catalogs, we open the relation, @@ -494,10 +542,18 @@ pg_get_tablecolumnoptionsdef_string(Oid tableRelationId) relationName = generate_relation_name(tableRelationId, NIL); relationKind = relation->rd_rel->relkind; - if (relationKind != RELKIND_RELATION && relationKind != RELKIND_FOREIGN_TABLE) + supportedRelationKind = (relationKind == RELKIND_RELATION || relationKind == + RELKIND_FOREIGN_TABLE); +#if (PG_VERSION_NUM >= 100000) + supportedRelationKind = supportedRelationKind || relationKind == + RELKIND_PARTITIONED_TABLE; +#endif + + if (!supportedRelationKind) { ereport(ERROR, (errcode(ERRCODE_WRONG_OBJECT_TYPE), - errmsg("%s is not a regular or foreign table", relationName))); + errmsg("%s is not a regular or foreign table or partitioned", + relationName))); } /* diff --git a/src/backend/distributed/utils/multi_partitioning_utils.c b/src/backend/distributed/utils/multi_partitioning_utils.c new file mode 100644 index 000000000..23dcdde1e --- /dev/null +++ b/src/backend/distributed/utils/multi_partitioning_utils.c @@ -0,0 +1,353 @@ +/* + * multi_partitioning_utils.c + * Utility functions for declarative partitioning + * + * Copyright (c) 2017, Citus Data, Inc. + */ +#include "postgres.h" + +#include "access/genam.h" +#include "access/heapam.h" +#include "access/htup_details.h" +#include "catalog/indexing.h" +#if (PG_VERSION_NUM >= 100000) +#include "catalog/partition.h" +#endif +#include "catalog/pg_class.h" +#include "catalog/pg_inherits.h" +#include "catalog/pg_inherits_fn.h" +#include "distributed/citus_ruleutils.h" +#include +#include "lib/stringinfo.h" +#include "nodes/pg_list.h" +#include "utils/builtins.h" +#include "utils/fmgroids.h" +#include "utils/lsyscache.h" +#include "utils/syscache.h" + + +#if (PG_VERSION_NUM >= 100000) +static char * PartitionBound(Oid partitionId); +#endif + + +/* + * Returns true if the given relation is a partitioned table. + */ +bool +PartitionedTable(Oid relationId) +{ + Relation rel = heap_open(relationId, AccessShareLock); + bool partitionedTable = false; + +#if (PG_VERSION_NUM >= 100000) + if (rel->rd_rel->relkind == RELKIND_PARTITIONED_TABLE) + { + partitionedTable = true; + } +#endif + + /* keep the lock */ + heap_close(rel, NoLock); + + return partitionedTable; +} + + +/* + * Returns true if the given relation is a partition. + */ +bool +PartitionTable(Oid relationId) +{ + Relation rel = heap_open(relationId, AccessShareLock); + bool partitionTable = false; + +#if (PG_VERSION_NUM >= 100000) + partitionTable = rel->rd_rel->relispartition; +#endif + + /* keep the lock */ + heap_close(rel, NoLock); + + return partitionTable; +} + + +/* + * IsChildTable returns true if the table is inherited. Note that + * partition tables inherites by default. However, this function + * returns false if the given table is a partition. + */ +bool +IsChildTable(Oid relationId) +{ + Relation pgInherits = NULL; + SysScanDesc scan = NULL; + ScanKeyData key[1]; + HeapTuple inheritsTuple = NULL; + bool tableInherits = false; + + pgInherits = heap_open(InheritsRelationId, AccessShareLock); + + ScanKeyInit(&key[0], Anum_pg_inherits_inhrelid, + BTEqualStrategyNumber, F_OIDEQ, + ObjectIdGetDatum(relationId)); + + scan = systable_beginscan(pgInherits, InvalidOid, false, + NULL, 1, key); + + while ((inheritsTuple = systable_getnext(scan)) != NULL) + { + Oid inheritedRelationId = + ((Form_pg_inherits) GETSTRUCT(inheritsTuple))->inhrelid; + + if (relationId == inheritedRelationId) + { + tableInherits = true; + break; + } + } + + systable_endscan(scan); + heap_close(pgInherits, AccessShareLock); + + if (tableInherits && PartitionTable(relationId)) + { + tableInherits = false; + } + + return tableInherits; +} + + +/* + * IsParentTable returns true if the table is inherited. Note that + * partitioned tables inherited by default. However, this function + * returns false if the given table is a partitioned table. + */ +bool +IsParentTable(Oid relationId) +{ + Relation pgInherits = NULL; + SysScanDesc scan = NULL; + ScanKeyData key[1]; + bool tableInherited = false; + + pgInherits = heap_open(InheritsRelationId, AccessShareLock); + + ScanKeyInit(&key[0], Anum_pg_inherits_inhparent, + BTEqualStrategyNumber, F_OIDEQ, + ObjectIdGetDatum(relationId)); + + scan = systable_beginscan(pgInherits, InheritsParentIndexId, true, + NULL, 1, key); + + if (systable_getnext(scan) != NULL) + { + tableInherited = true; + } + systable_endscan(scan); + heap_close(pgInherits, AccessShareLock); + + if (tableInherited && PartitionedTable(relationId)) + { + tableInherited = false; + } + + return tableInherited; +} + + +/* + * Takes a parent relation and returns Oid list of its partitions. The + * function errors out if the given relation is not a parent. + */ +List * +PartitionList(Oid parentRelationId) +{ + Relation rel = heap_open(parentRelationId, AccessShareLock); + List *partitionList = NIL; + +#if (PG_VERSION_NUM >= 100000) + int partitionIndex = 0; + int partitionCount = 0; + + if (!PartitionedTable(parentRelationId)) + { + char *relationName = get_rel_name(parentRelationId); + + ereport(ERROR, (errmsg("\"%s\" is not a parent table", relationName))); + } + + Assert(rel->rd_partdesc != NULL); + + partitionCount = rel->rd_partdesc->nparts; + for (partitionIndex = 0; partitionIndex < partitionCount; ++partitionIndex) + { + partitionList = + lappend_oid(partitionList, rel->rd_partdesc->oids[partitionIndex]); + } +#endif + + /* keep the lock */ + heap_close(rel, NoLock); + + return partitionList; +} + + +/* + * GenerateDetachPartitionCommand gets a partition table and returns + * "ALTER TABLE parent_table DETACH PARTITION partitionName" command. + */ +char * +GenerateDetachPartitionCommand(Oid partitionTableId) +{ + StringInfo detachPartitionCommand = makeStringInfo(); + +#if (PG_VERSION_NUM >= 100000) + Oid parentId = InvalidOid; + char *tableQualifiedName = NULL; + char *parentTableQualifiedName = NULL; + + if (!PartitionTable(partitionTableId)) + { + char *relationName = get_rel_name(partitionTableId); + + ereport(ERROR, (errmsg("\"%s\" is not a partition", relationName))); + } + + parentId = get_partition_parent(partitionTableId); + tableQualifiedName = generate_qualified_relation_name(partitionTableId); + parentTableQualifiedName = generate_qualified_relation_name(parentId); + + appendStringInfo(detachPartitionCommand, "ALTER TABLE %s DETACH PARTITION %s;", + parentTableQualifiedName, tableQualifiedName); +#endif + + return detachPartitionCommand->data; +} + + +/* + * GenereatePartitioningInformation returns the partitioning type and partition column + * for the given parent table in the form of "PARTITION TYPE (partitioning column(s)/expression(s))". + */ +char * +GeneratePartitioningInformation(Oid parentTableId) +{ + char *partitionBoundCString = ""; + +#if (PG_VERSION_NUM >= 100000) + Datum partitionBoundDatum = 0; + + if (!PartitionedTable(parentTableId)) + { + char *relationName = get_rel_name(parentTableId); + + ereport(ERROR, (errmsg("\"%s\" is not a parent table", relationName))); + } + + partitionBoundDatum = DirectFunctionCall1(pg_get_partkeydef, + ObjectIdGetDatum(parentTableId)); + + partitionBoundCString = TextDatumGetCString(partitionBoundDatum); +#endif + + return partitionBoundCString; +} + + +/* + * GenerateAlterTableAttachPartitionCommand returns the necessary command to + * attach the given partition to its parent. + */ +char * +GenerateAlterTableAttachPartitionCommand(Oid partitionTableId) +{ + StringInfo createPartitionCommand = makeStringInfo(); + +#if (PG_VERSION_NUM >= 100000) + char *partitionBoundCString = NULL; + + Oid parentId = InvalidOid; + char *tableQualifiedName = NULL; + char *parentTableQualifiedName = NULL; + + if (!PartitionTable(partitionTableId)) + { + char *relationName = get_rel_name(partitionTableId); + + ereport(ERROR, (errmsg("\"%s\" is not a partition", relationName))); + } + + parentId = get_partition_parent(partitionTableId); + tableQualifiedName = generate_qualified_relation_name(partitionTableId); + parentTableQualifiedName = generate_qualified_relation_name(parentId); + + partitionBoundCString = PartitionBound(partitionTableId); + + appendStringInfo(createPartitionCommand, "ALTER TABLE %s ATTACH PARTITION %s %s;", + parentTableQualifiedName, tableQualifiedName, + partitionBoundCString); +#endif + + return createPartitionCommand->data; +} + + +#if (PG_VERSION_NUM >= 100000) + +/* + * This function heaviliy inspired from RelationBuildPartitionDesc() + * which is avaliable in src/backend/catalog/partition.c. + * + * The function simply reads the pg_class and gets the partition bound. + * Later, converts it to text format and returns. + */ +static char * +PartitionBound(Oid partitionId) +{ + char *partitionBoundString = NULL; + HeapTuple tuple = NULL; + Datum datum = 0; + bool isnull = false; + Datum partitionBoundDatum = 0; + + tuple = SearchSysCache1(RELOID, partitionId); + if (!HeapTupleIsValid(tuple)) + { + elog(ERROR, "cache lookup failed for relation %u", partitionId); + } + + /* + * It is possible that the pg_class tuple of a partition has not been + * updated yet to set its relpartbound field. The only case where + * this happens is when we open the parent relation to check using its + * partition descriptor that a new partition's bound does not overlap + * some existing partition. + */ + if (!((Form_pg_class) GETSTRUCT(tuple))->relispartition) + { + ReleaseSysCache(tuple); + return ""; + } + + datum = SysCacheGetAttr(RELOID, tuple, + Anum_pg_class_relpartbound, + &isnull); + Assert(!isnull); + + partitionBoundDatum = + DirectFunctionCall2(pg_get_expr, datum, ObjectIdGetDatum(partitionId)); + + partitionBoundString = TextDatumGetCString(partitionBoundDatum); + + ReleaseSysCache(tuple); + + return partitionBoundString; +} + + +#endif diff --git a/src/backend/distributed/utils/reference_table_utils.c b/src/backend/distributed/utils/reference_table_utils.c index ecda24eb1..a8b13d5d9 100644 --- a/src/backend/distributed/utils/reference_table_utils.c +++ b/src/backend/distributed/utils/reference_table_utils.c @@ -39,7 +39,6 @@ static void ReplicateShardToAllWorkers(ShardInterval *shardInterval); static void ReplicateShardToNode(ShardInterval *shardInterval, char *nodeName, int nodePort); static void ConvertToReferenceTableMetadata(Oid relationId, uint64 shardId); -static int CompareOids(const void *leftElement, const void *rightElement); /* exports for SQL callable functions */ PG_FUNCTION_INFO_V1(upgrade_to_reference_table); @@ -457,7 +456,7 @@ ReferenceTableOidList() /* CompareOids is a comparison function for sort shard oids */ -static int +int CompareOids(const void *leftElement, const void *rightElement) { Oid *leftId = (Oid *) leftElement; diff --git a/src/include/distributed/multi_partitioning_utils.h b/src/include/distributed/multi_partitioning_utils.h new file mode 100644 index 000000000..4dc5f0616 --- /dev/null +++ b/src/include/distributed/multi_partitioning_utils.h @@ -0,0 +1,24 @@ +/* + * multi_partitioning_utils.h + * Utility functions declarations for declarative partitioning + * + * Copyright (c) 2017, Citus Data, Inc. + */ +#ifndef MULTI_PARTITIONING_UTILS_H_ +#define MULTI_PARTITIONING_UTILS_H_ + + +#include "nodes/pg_list.h" + + +extern bool PartitionedTable(Oid relationId); +extern bool PartitionTable(Oid relationId); +extern bool IsChildTable(Oid relationId); +extern bool IsParentTable(Oid relationId); +extern List * PartitionList(Oid parentRelationId); +extern char * GenerateDetachPartitionCommand(Oid partitionTableId); +extern char * GenerateAlterTableAttachPartitionCommand(Oid partitionTableId); +extern char * GeneratePartitioningInformation(Oid tableId); + + +#endif /* MULTI_PARTITIONING_UTILS_H_ */ diff --git a/src/include/distributed/reference_table_utils.h b/src/include/distributed/reference_table_utils.h index f2b083bbf..feed8fe32 100644 --- a/src/include/distributed/reference_table_utils.h +++ b/src/include/distributed/reference_table_utils.h @@ -17,5 +17,7 @@ extern void ReplicateAllReferenceTablesToNode(char *nodeName, int nodePort); extern void DeleteAllReferenceTablePlacementsFromNode(char *workerName, uint32 workerPort); extern List * ReferenceTableOidList(void); +extern int CompareOids(const void *leftElement, const void *rightElement); + #endif /* REFERENCE_TABLE_UTILS_H_ */ diff --git a/src/test/regress/expected/multi_generate_ddl_commands.out b/src/test/regress/expected/multi_generate_ddl_commands.out index 5b9a2c66c..d993abf29 100644 --- a/src/test/regress/expected/multi_generate_ddl_commands.out +++ b/src/test/regress/expected/multi_generate_ddl_commands.out @@ -146,7 +146,7 @@ NOTICE: foreign-data wrapper "fake_fdw" does not have an extension defined -- propagating views is not supported CREATE VIEW local_view AS SELECT * FROM simple_table; SELECT table_ddl_command_array('local_view'); -ERROR: public.local_view is not a regular or foreign table +ERROR: public.local_view is not a regular, foreign, or partitioned table -- clean up DROP VIEW IF EXISTS local_view; DROP FOREIGN TABLE IF EXISTS foreign_table; diff --git a/src/test/regress/expected/multi_partitioning_utils.out b/src/test/regress/expected/multi_partitioning_utils.out new file mode 100644 index 000000000..49e8d5f13 --- /dev/null +++ b/src/test/regress/expected/multi_partitioning_utils.out @@ -0,0 +1,422 @@ +-- =================================================================== +-- create test functions +-- =================================================================== +CREATE FUNCTION generate_alter_table_detach_partition_command(regclass) + RETURNS text + AS 'citus' + LANGUAGE C STRICT; +CREATE FUNCTION generate_alter_table_attach_partition_command(regclass) + RETURNS text + AS 'citus' + LANGUAGE C STRICT; +CREATE FUNCTION generate_partition_information(regclass) + RETURNS text + AS 'citus' + LANGUAGE C STRICT; +CREATE FUNCTION print_partitions(regclass) + RETURNS text + AS 'citus' + LANGUAGE C STRICT; +CREATE FUNCTION table_inherits(regclass) + RETURNS bool + AS 'citus' + LANGUAGE C STRICT; +CREATE FUNCTION table_inherited(regclass) + RETURNS bool + AS 'citus' + LANGUAGE C STRICT; +CREATE OR REPLACE FUNCTION detach_and_attach_partition(partition_name regclass, parent_table_name regclass) +RETURNS void LANGUAGE plpgsql VOLATILE +AS $function$ +DECLARE + detach_partition_command text := ''; + attach_partition_command text := ''; + command_result text := ''; + +BEGIN + -- first generate the command + SELECT public.generate_alter_table_attach_partition_command(partition_name) INTO attach_partition_command; + + -- now genereate the detach command + SELECT public.generate_alter_table_detach_partition_command(partition_name) INTO detach_partition_command; + + -- later detach the same partition + EXECUTE detach_partition_command; + + -- not attach it again + EXECUTE attach_partition_command; +END; +$function$; +CREATE OR REPLACE FUNCTION drop_and_recreate_partitioned_table(parent_table_name regclass) +RETURNS void LANGUAGE plpgsql VOLATILE +AS $function$ +DECLARE + command text := ''; + +BEGIN + -- first generate the command + CREATE TABLE partitioned_table_create_commands AS SELECT master_get_table_ddl_events(parent_table_name::text); + + -- later detach the same partition + EXECUTE 'DROP TABLE ' || parent_table_name::text || ';'; + + FOR command IN SELECT * FROM partitioned_table_create_commands + LOOP + -- can do some processing here + EXECUTE command; + END LOOP; + + DROP TABLE partitioned_table_create_commands; + +END; +$function$; +-- create a partitioned table +CREATE TABLE date_partitioned_table(id int, time date) PARTITION BY RANGE (time); +-- we should be able to get the partitioning information even if there are no partitions +SELECT generate_partition_information('date_partitioned_table'); + generate_partition_information +-------------------------------- + RANGE ("time") +(1 row) + +-- we should be able to drop and re-create the partitioned table using the command that Citus generate +SELECT drop_and_recreate_partitioned_table('date_partitioned_table'); + drop_and_recreate_partitioned_table +------------------------------------- + +(1 row) + +-- we should also be able to see the PARTITION BY ... for the parent table +SELECT master_get_table_ddl_events('date_partitioned_table'); + master_get_table_ddl_events +--------------------------------------------------------------------------------------------------- + CREATE TABLE public.date_partitioned_table (id integer, "time" date) PARTITION BY RANGE ("time") +(1 row) + +-- now create the partitions +CREATE TABLE date_partition_2006 PARTITION OF date_partitioned_table FOR VALUES FROM ('2006-01-01') TO ('2007-01-01'); +CREATE TABLE date_partition_2007 PARTITION OF date_partitioned_table FOR VALUES FROM ('2007-01-01') TO ('2008-01-01'); +-- we should be able to get the partitioning information after the partitions are created +SELECT generate_partition_information('date_partitioned_table'); + generate_partition_information +-------------------------------- + RANGE ("time") +(1 row) + +-- lets get the attach partition commands +SELECT generate_alter_table_attach_partition_command('date_partition_2006'); + generate_alter_table_attach_partition_command +----------------------------------------------------------------------------------------------------------------------------------------- + ALTER TABLE public.date_partitioned_table ATTACH PARTITION public.date_partition_2006 FOR VALUES FROM ('01-01-2006') TO ('01-01-2007'); +(1 row) + +SELECT generate_alter_table_attach_partition_command('date_partition_2007'); + generate_alter_table_attach_partition_command +----------------------------------------------------------------------------------------------------------------------------------------- + ALTER TABLE public.date_partitioned_table ATTACH PARTITION public.date_partition_2007 FOR VALUES FROM ('01-01-2007') TO ('01-01-2008'); +(1 row) + +-- detach and attach the partition by the command generated by us +\d+ date_partitioned_table + Table "public.date_partitioned_table" + Column | Type | Collation | Nullable | Default | Storage | Stats target | Description +--------+---------+-----------+----------+---------+---------+--------------+------------- + id | integer | | | | plain | | + time | date | | | | plain | | +Partition key: RANGE ("time") +Partitions: date_partition_2006 FOR VALUES FROM ('01-01-2006') TO ('01-01-2007'), + date_partition_2007 FOR VALUES FROM ('01-01-2007') TO ('01-01-2008') + +SELECT detach_and_attach_partition('date_partition_2007', 'date_partitioned_table'); + detach_and_attach_partition +----------------------------- + +(1 row) + +-- check that both partitions are visiable +\d+ date_partitioned_table + Table "public.date_partitioned_table" + Column | Type | Collation | Nullable | Default | Storage | Stats target | Description +--------+---------+-----------+----------+---------+---------+--------------+------------- + id | integer | | | | plain | | + time | date | | | | plain | | +Partition key: RANGE ("time") +Partitions: date_partition_2006 FOR VALUES FROM ('01-01-2006') TO ('01-01-2007'), + date_partition_2007 FOR VALUES FROM ('01-01-2007') TO ('01-01-2008') + +-- make sure that inter shard commands work as expected +-- assume that the shardId is 100 +CREATE TABLE date_partitioned_table_100 (id int, time date) PARTITION BY RANGE (time); +CREATE TABLE date_partition_2007_100 (id int, time date ); +-- now create the partitioning hierarcy +SELECT worker_apply_inter_shard_ddl_command(referencing_shard:=100, referencing_schema_name:='public', + referenced_shard:=100, referenced_schema_name:='public', + command:='ALTER TABLE date_partitioned_table ATTACH PARTITION date_partition_2007 FOR VALUES FROM (''2007-01-01'') TO (''2008-01-02'')' ); + worker_apply_inter_shard_ddl_command +-------------------------------------- + +(1 row) + +-- the hierarcy is successfully created +\d+ date_partitioned_table_100 + Table "public.date_partitioned_table_100" + Column | Type | Collation | Nullable | Default | Storage | Stats target | Description +--------+---------+-----------+----------+---------+---------+--------------+------------- + id | integer | | | | plain | | + time | date | | | | plain | | +Partition key: RANGE ("time") +Partitions: date_partition_2007_100 FOR VALUES FROM ('01-01-2007') TO ('01-02-2008') + +-- Citus can also get the DDL events for the partitions as regular tables +SELECT master_get_table_ddl_events('date_partition_2007_100'); + master_get_table_ddl_events +----------------------------------------------------------------------- + CREATE TABLE public.date_partition_2007_100 (id integer, "time" date) +(1 row) + +-- now break the partitioning hierarcy +SELECT worker_apply_inter_shard_ddl_command(referencing_shard:=100, referencing_schema_name:='public', + referenced_shard:=100, referenced_schema_name:='public', + command:='ALTER TABLE date_partitioned_table DETACH PARTITION date_partition_2007' ); + worker_apply_inter_shard_ddl_command +-------------------------------------- + +(1 row) + +-- the hierarcy is successfully broken +\d+ date_partitioned_table_100 + Table "public.date_partitioned_table_100" + Column | Type | Collation | Nullable | Default | Storage | Stats target | Description +--------+---------+-----------+----------+---------+---------+--------------+------------- + id | integer | | | | plain | | + time | date | | | | plain | | +Partition key: RANGE ("time") + +-- now lets have some more complex partitioning hierarcies with +-- tables on different schemas and constraints on the tables +CREATE SCHEMA partition_parent_schema; +CREATE TABLE partition_parent_schema.parent_table (id int NOT NULL, time date DEFAULT now()) PARTITION BY RANGE (time); +CREATE SCHEMA partition_child_1_schema; +CREATE TABLE partition_child_1_schema.child_1 (id int NOT NULL, time date ); +CREATE SCHEMA partition_child_2_schema; +CREATE TABLE partition_child_2_schema.child_2 (id int NOT NULL, time date ); +-- we should be able to get the partitioning information even if there are no partitions +SELECT generate_partition_information('partition_parent_schema.parent_table'); + generate_partition_information +-------------------------------- + RANGE ("time") +(1 row) + +-- we should be able to drop and re-create the partitioned table using the command that Citus generate +SELECT drop_and_recreate_partitioned_table('partition_parent_schema.parent_table'); +NOTICE: schema "partition_parent_schema" already exists, skipping +CONTEXT: SQL statement "CREATE SCHEMA IF NOT EXISTS partition_parent_schema AUTHORIZATION postgres" +PL/pgSQL function drop_and_recreate_partitioned_table(regclass) line 15 at EXECUTE + drop_and_recreate_partitioned_table +------------------------------------- + +(1 row) + +ALTER TABLE partition_parent_schema.parent_table ATTACH PARTITION partition_child_1_schema.child_1 FOR VALUES FROM ('2009-01-01') TO ('2010-01-02'); +SET search_path = 'partition_parent_schema'; +ALTER TABLE parent_table ATTACH PARTITION partition_child_2_schema.child_2 FOR VALUES FROM ('2006-01-01') TO ('2007-01-01'); +SELECT public.generate_partition_information('parent_table'); + generate_partition_information +-------------------------------- + RANGE ("time") +(1 row) + +-- lets get the attach partition commands +SELECT public.generate_alter_table_attach_partition_command('partition_child_1_schema.child_1'); + generate_alter_table_attach_partition_command +------------------------------------------------------------------------------------------------------------------------------------------------------ + ALTER TABLE partition_parent_schema.parent_table ATTACH PARTITION partition_child_1_schema.child_1 FOR VALUES FROM ('01-01-2009') TO ('01-02-2010'); +(1 row) + +SET search_path = 'partition_child_2_schema'; +SELECT public.generate_alter_table_attach_partition_command('child_2'); + generate_alter_table_attach_partition_command +------------------------------------------------------------------------------------------------------------------------------------------------------ + ALTER TABLE partition_parent_schema.parent_table ATTACH PARTITION partition_child_2_schema.child_2 FOR VALUES FROM ('01-01-2006') TO ('01-01-2007'); +(1 row) + +SET search_path = 'partition_parent_schema'; +-- detach and attach the partition by the command generated by us +\d+ parent_table + Table "partition_parent_schema.parent_table" + Column | Type | Collation | Nullable | Default | Storage | Stats target | Description +--------+---------+-----------+----------+---------+---------+--------------+------------- + id | integer | | not null | | plain | | + time | date | | | now() | plain | | +Partition key: RANGE ("time") +Partitions: partition_child_1_schema.child_1 FOR VALUES FROM ('01-01-2009') TO ('01-02-2010'), + partition_child_2_schema.child_2 FOR VALUES FROM ('01-01-2006') TO ('01-01-2007') + +SELECT public.detach_and_attach_partition('partition_child_1_schema.child_1', 'parent_table'); + detach_and_attach_partition +----------------------------- + +(1 row) + +-- check that both partitions are visiable +\d+ parent_table + Table "partition_parent_schema.parent_table" + Column | Type | Collation | Nullable | Default | Storage | Stats target | Description +--------+---------+-----------+----------+---------+---------+--------------+------------- + id | integer | | not null | | plain | | + time | date | | | now() | plain | | +Partition key: RANGE ("time") +Partitions: partition_child_1_schema.child_1 FOR VALUES FROM ('01-01-2009') TO ('01-02-2010'), + partition_child_2_schema.child_2 FOR VALUES FROM ('01-01-2006') TO ('01-01-2007') + +-- some very simple checks that should error out +SELECT public.generate_alter_table_attach_partition_command('parent_table'); +ERROR: "parent_table" is not a partition +SELECT public.generate_partition_information('partition_child_1_schema.child_1'); +ERROR: "child_1" is not a parent table +SELECT public.print_partitions('partition_child_1_schema.child_1'); +ERROR: "child_1" is not a parent table +-- now pring the partitions +SELECT public.print_partitions('parent_table'); + print_partitions +------------------ + child_1,child_2 +(1 row) + +SET search_path = 'public'; +-- test multi column / expression partitioning with UNBOUNDED ranges +CREATE OR REPLACE FUNCTION some_function(input_val text) +RETURNS text LANGUAGE plpgsql IMMUTABLE +AS $function$ +BEGIN + return reverse(input_val); +END; +$function$; +CREATE TABLE multi_column_partitioned ( + a int, + b int, + c text + ) PARTITION BY RANGE (a, (a+b+1), some_function(upper(c))); +CREATE TABLE multi_column_partition_1( + a int, + b int, + c text +); +CREATE TABLE multi_column_partition_2( + a int, + b int, + c text +); +-- partitioning information +SELECT generate_partition_information('multi_column_partitioned'); + generate_partition_information +--------------------------------------------------- + RANGE (a, ((a + b) + 1), some_function(upper(c))) +(1 row) + +SELECT master_get_table_ddl_events('multi_column_partitioned'); + master_get_table_ddl_events +---------------------------------------------------------------------------------------------------------------------------------------------------- + CREATE TABLE public.multi_column_partitioned (a integer, b integer, c text) PARTITION BY RANGE (a, ((a + b) + 1), public.some_function(upper(c))) +(1 row) + +SELECT drop_and_recreate_partitioned_table('multi_column_partitioned'); + drop_and_recreate_partitioned_table +------------------------------------- + +(1 row) + +-- partitions and their ranges +ALTER TABLE multi_column_partitioned ATTACH PARTITION multi_column_partition_1 FOR VALUES FROM (1, 10, '250') TO (1, 20, '250'); +SELECT generate_alter_table_attach_partition_command('multi_column_partition_1'); + generate_alter_table_attach_partition_command +-------------------------------------------------------------------------------------------------------------------------------------------- + ALTER TABLE public.multi_column_partitioned ATTACH PARTITION public.multi_column_partition_1 FOR VALUES FROM (1, 10, 250) TO (1, 20, 250); +(1 row) + +ALTER TABLE multi_column_partitioned ATTACH PARTITION multi_column_partition_2 FOR VALUES FROM (10, 1000, '2500') TO (UNBOUNDED, UNBOUNDED, UNBOUNDED); +SELECT generate_alter_table_attach_partition_command('multi_column_partition_2'); + generate_alter_table_attach_partition_command +--------------------------------------------------------------------------------------------------------------------------------------------------------------------- + ALTER TABLE public.multi_column_partitioned ATTACH PARTITION public.multi_column_partition_2 FOR VALUES FROM (10, 1000, 2500) TO (UNBOUNDED, UNBOUNDED, UNBOUNDED); +(1 row) + +SELECT generate_alter_table_detach_partition_command('multi_column_partition_2'); + generate_alter_table_detach_partition_command +----------------------------------------------------------------------------------------------- + ALTER TABLE public.multi_column_partitioned DETACH PARTITION public.multi_column_partition_2; +(1 row) + +-- finally a test with LIST partitioning +CREATE TABLE list_partitioned (col1 NUMERIC, col2 NUMERIC, col3 VARCHAR(10)) PARTITION BY LIST (col1) ; +SELECT generate_partition_information('list_partitioned'); + generate_partition_information +-------------------------------- + LIST (col1) +(1 row) + +SELECT master_get_table_ddl_events('list_partitioned'); + master_get_table_ddl_events +------------------------------------------------------------------------------------------------------------------------- + CREATE TABLE public.list_partitioned (col1 numeric, col2 numeric, col3 character varying(10)) PARTITION BY LIST (col1) +(1 row) + +SELECT drop_and_recreate_partitioned_table('list_partitioned'); + drop_and_recreate_partitioned_table +------------------------------------- + +(1 row) + +CREATE TABLE list_partitioned_1 PARTITION OF list_partitioned FOR VALUES IN (100, 101, 102, 103, 104); +SELECT generate_alter_table_attach_partition_command('list_partitioned_1'); + generate_alter_table_attach_partition_command +----------------------------------------------------------------------------------------------------------------------------------- + ALTER TABLE public.list_partitioned ATTACH PARTITION public.list_partitioned_1 FOR VALUES IN ('100', '101', '102', '103', '104'); +(1 row) + +-- also differentiate partitions and inhereted tables +CREATE TABLE cities ( + name text, + population float, + altitude int -- in feet +); +CREATE TABLE capitals ( + state char(2) +) INHERITS (cities); +-- returns true since capitals inherits from cities +SELECT table_inherits('capitals'); + table_inherits +---------------- + t +(1 row) + +-- although date_partition_2006 inherits from its parent +-- returns false since the hierarcy is formed via partitioning +SELECT table_inherits('date_partition_2006'); + table_inherits +---------------- + f +(1 row) + +-- returns true since cities inherited by capitals +SELECT table_inherited('cities'); + table_inherited +----------------- + t +(1 row) + +-- although date_partitioned_table inherited by its partitions +-- returns false since the hierarcy is formed via partitioning +SELECT table_inherited('date_partitioned_table'); + table_inherited +----------------- + f +(1 row) + +-- also these are not supported +SELECT master_get_table_ddl_events('capitals'); +ERROR: public.capitals is not a regular, foreign, or partitioned table +SELECT master_get_table_ddl_events('cities'); +ERROR: public.cities is not a regular, foreign, or partitioned table +-- dropping parents frop the partitions +DROP TABLE date_partitioned_table, multi_column_partitioned, list_partitioned, partition_parent_schema.parent_table, cities, capitals; diff --git a/src/test/regress/expected/multi_partitioning_utils_0.out b/src/test/regress/expected/multi_partitioning_utils_0.out new file mode 100644 index 000000000..ac581e226 --- /dev/null +++ b/src/test/regress/expected/multi_partitioning_utils_0.out @@ -0,0 +1,363 @@ +-- =================================================================== +-- create test functions +-- =================================================================== +CREATE FUNCTION generate_alter_table_detach_partition_command(regclass) + RETURNS text + AS 'citus' + LANGUAGE C STRICT; +CREATE FUNCTION generate_alter_table_attach_partition_command(regclass) + RETURNS text + AS 'citus' + LANGUAGE C STRICT; +CREATE FUNCTION generate_partition_information(regclass) + RETURNS text + AS 'citus' + LANGUAGE C STRICT; +CREATE FUNCTION print_partitions(regclass) + RETURNS text + AS 'citus' + LANGUAGE C STRICT; +CREATE FUNCTION table_inherits(regclass) + RETURNS bool + AS 'citus' + LANGUAGE C STRICT; +CREATE FUNCTION table_inherited(regclass) + RETURNS bool + AS 'citus' + LANGUAGE C STRICT; +CREATE OR REPLACE FUNCTION detach_and_attach_partition(partition_name regclass, parent_table_name regclass) +RETURNS void LANGUAGE plpgsql VOLATILE +AS $function$ +DECLARE + detach_partition_command text := ''; + attach_partition_command text := ''; + command_result text := ''; + +BEGIN + -- first generate the command + SELECT public.generate_alter_table_attach_partition_command(partition_name) INTO attach_partition_command; + + -- now genereate the detach command + SELECT public.generate_alter_table_detach_partition_command(partition_name) INTO detach_partition_command; + + -- later detach the same partition + EXECUTE detach_partition_command; + + -- not attach it again + EXECUTE attach_partition_command; +END; +$function$; +CREATE OR REPLACE FUNCTION drop_and_recreate_partitioned_table(parent_table_name regclass) +RETURNS void LANGUAGE plpgsql VOLATILE +AS $function$ +DECLARE + command text := ''; + +BEGIN + -- first generate the command + CREATE TABLE partitioned_table_create_commands AS SELECT master_get_table_ddl_events(parent_table_name::text); + + -- later detach the same partition + EXECUTE 'DROP TABLE ' || parent_table_name::text || ';'; + + FOR command IN SELECT * FROM partitioned_table_create_commands + LOOP + -- can do some processing here + EXECUTE command; + END LOOP; + + DROP TABLE partitioned_table_create_commands; + +END; +$function$; +-- create a partitioned table +CREATE TABLE date_partitioned_table(id int, time date) PARTITION BY RANGE (time); +ERROR: syntax error at or near "PARTITION" +LINE 1: ...E TABLE date_partitioned_table(id int, time date) PARTITION ... + ^ +-- we should be able to get the partitioning information even if there are no partitions +SELECT generate_partition_information('date_partitioned_table'); +ERROR: relation "date_partitioned_table" does not exist +LINE 1: SELECT generate_partition_information('date_partitioned_tabl... + ^ +-- we should be able to drop and re-create the partitioned table using the command that Citus generate +SELECT drop_and_recreate_partitioned_table('date_partitioned_table'); +ERROR: relation "date_partitioned_table" does not exist +LINE 1: SELECT drop_and_recreate_partitioned_table('date_partitioned... + ^ +-- we should also be able to see the PARTITION BY ... for the parent table +SELECT master_get_table_ddl_events('date_partitioned_table'); +ERROR: relation "date_partitioned_table" does not exist +-- now create the partitions +CREATE TABLE date_partition_2006 PARTITION OF date_partitioned_table FOR VALUES FROM ('2006-01-01') TO ('2007-01-01'); +ERROR: syntax error at or near "PARTITION" +LINE 1: CREATE TABLE date_partition_2006 PARTITION OF date_partition... + ^ +CREATE TABLE date_partition_2007 PARTITION OF date_partitioned_table FOR VALUES FROM ('2007-01-01') TO ('2008-01-01'); +ERROR: syntax error at or near "PARTITION" +LINE 1: CREATE TABLE date_partition_2007 PARTITION OF date_partition... + ^ +-- we should be able to get the partitioning information after the partitions are created +SELECT generate_partition_information('date_partitioned_table'); +ERROR: relation "date_partitioned_table" does not exist +LINE 1: SELECT generate_partition_information('date_partitioned_tabl... + ^ +-- lets get the attach partition commands +SELECT generate_alter_table_attach_partition_command('date_partition_2006'); +ERROR: relation "date_partition_2006" does not exist +LINE 1: ...ECT generate_alter_table_attach_partition_command('date_part... + ^ +SELECT generate_alter_table_attach_partition_command('date_partition_2007'); +ERROR: relation "date_partition_2007" does not exist +LINE 1: ...ECT generate_alter_table_attach_partition_command('date_part... + ^ +-- detach and attach the partition by the command generated by us +\d+ date_partitioned_table +SELECT detach_and_attach_partition('date_partition_2007', 'date_partitioned_table'); +ERROR: relation "date_partition_2007" does not exist +LINE 1: SELECT detach_and_attach_partition('date_partition_2007', 'd... + ^ +-- check that both partitions are visiable +\d+ date_partitioned_table +-- make sure that inter shard commands work as expected +-- assume that the shardId is 100 +CREATE TABLE date_partitioned_table_100 (id int, time date) PARTITION BY RANGE (time); +ERROR: syntax error at or near "PARTITION" +LINE 1: ...LE date_partitioned_table_100 (id int, time date) PARTITION ... + ^ +CREATE TABLE date_partition_2007_100 (id int, time date ); +-- now create the partitioning hierarcy +SELECT worker_apply_inter_shard_ddl_command(referencing_shard:=100, referencing_schema_name:='public', + referenced_shard:=100, referenced_schema_name:='public', + command:='ALTER TABLE date_partitioned_table ATTACH PARTITION date_partition_2007 FOR VALUES FROM (''2007-01-01'') TO (''2008-01-02'')' ); +ERROR: syntax error at or near "ATTACH" +LINE 1: SELECT worker_apply_inter_shard_ddl_command(referencing_shar... + ^ +-- the hierarcy is successfully created +\d+ date_partitioned_table_100 +-- Citus can also get the DDL events for the partitions as regular tables +SELECT master_get_table_ddl_events('date_partition_2007_100'); + master_get_table_ddl_events +----------------------------------------------------------------------- + CREATE TABLE public.date_partition_2007_100 (id integer, "time" date) +(1 row) + +-- now break the partitioning hierarcy +SELECT worker_apply_inter_shard_ddl_command(referencing_shard:=100, referencing_schema_name:='public', + referenced_shard:=100, referenced_schema_name:='public', + command:='ALTER TABLE date_partitioned_table DETACH PARTITION date_partition_2007' ); +ERROR: syntax error at or near "DETACH" +LINE 1: SELECT worker_apply_inter_shard_ddl_command(referencing_shar... + ^ +-- the hierarcy is successfully broken +\d+ date_partitioned_table_100 +-- now lets have some more complex partitioning hierarcies with +-- tables on different schemas and constraints on the tables +CREATE SCHEMA partition_parent_schema; +CREATE TABLE partition_parent_schema.parent_table (id int NOT NULL, time date DEFAULT now()) PARTITION BY RANGE (time); +ERROR: syntax error at or near "PARTITION" +LINE 1: ..._table (id int NOT NULL, time date DEFAULT now()) PARTITION ... + ^ +CREATE SCHEMA partition_child_1_schema; +CREATE TABLE partition_child_1_schema.child_1 (id int NOT NULL, time date ); +CREATE SCHEMA partition_child_2_schema; +CREATE TABLE partition_child_2_schema.child_2 (id int NOT NULL, time date ); +-- we should be able to get the partitioning information even if there are no partitions +SELECT generate_partition_information('partition_parent_schema.parent_table'); +ERROR: relation "partition_parent_schema.parent_table" does not exist +LINE 1: SELECT generate_partition_information('partition_parent_sche... + ^ +-- we should be able to drop and re-create the partitioned table using the command that Citus generate +SELECT drop_and_recreate_partitioned_table('partition_parent_schema.parent_table'); +ERROR: relation "partition_parent_schema.parent_table" does not exist +LINE 1: SELECT drop_and_recreate_partitioned_table('partition_parent... + ^ +ALTER TABLE partition_parent_schema.parent_table ATTACH PARTITION partition_child_1_schema.child_1 FOR VALUES FROM ('2009-01-01') TO ('2010-01-02'); +ERROR: syntax error at or near "ATTACH" +LINE 1: ALTER TABLE partition_parent_schema.parent_table ATTACH PART... + ^ +SET search_path = 'partition_parent_schema'; +ALTER TABLE parent_table ATTACH PARTITION partition_child_2_schema.child_2 FOR VALUES FROM ('2006-01-01') TO ('2007-01-01'); +ERROR: syntax error at or near "ATTACH" +LINE 1: ALTER TABLE parent_table ATTACH PARTITION partition_child_2... + ^ +SELECT public.generate_partition_information('parent_table'); +ERROR: relation "parent_table" does not exist +LINE 1: SELECT public.generate_partition_information('parent_table')... + ^ +-- lets get the attach partition commands +SELECT public.generate_alter_table_attach_partition_command('partition_child_1_schema.child_1'); + generate_alter_table_attach_partition_command +----------------------------------------------- + +(1 row) + +SET search_path = 'partition_child_2_schema'; +SELECT public.generate_alter_table_attach_partition_command('child_2'); + generate_alter_table_attach_partition_command +----------------------------------------------- + +(1 row) + +SET search_path = 'partition_parent_schema'; +-- detach and attach the partition by the command generated by us +\d+ parent_table +SELECT public.detach_and_attach_partition('partition_child_1_schema.child_1', 'parent_table'); +ERROR: relation "parent_table" does not exist +LINE 1: ...ach_partition('partition_child_1_schema.child_1', 'parent_ta... + ^ +-- check that both partitions are visiable +\d+ parent_table +-- some very simple checks that should error out +SELECT public.generate_alter_table_attach_partition_command('parent_table'); +ERROR: relation "parent_table" does not exist +LINE 1: ...lic.generate_alter_table_attach_partition_command('parent_ta... + ^ +SELECT public.generate_partition_information('partition_child_1_schema.child_1'); + generate_partition_information +-------------------------------- + +(1 row) + +SELECT public.print_partitions('partition_child_1_schema.child_1'); + print_partitions +------------------ + +(1 row) + +-- now pring the partitions +SELECT public.print_partitions('parent_table'); +ERROR: relation "parent_table" does not exist +LINE 1: SELECT public.print_partitions('parent_table'); + ^ +SET search_path = 'public'; +-- test multi column / expression partitioning with UNBOUNDED ranges +CREATE OR REPLACE FUNCTION some_function(input_val text) +RETURNS text LANGUAGE plpgsql IMMUTABLE +AS $function$ +BEGIN + return reverse(input_val); +END; +$function$; +CREATE TABLE multi_column_partitioned ( + a int, + b int, + c text + ) PARTITION BY RANGE (a, (a+b+1), some_function(upper(c))); +ERROR: syntax error at or near "PARTITION" +LINE 5: ) PARTITION BY RANGE (a, (a+b+1), some_function(upper(c))); + ^ +CREATE TABLE multi_column_partition_1( + a int, + b int, + c text +); +CREATE TABLE multi_column_partition_2( + a int, + b int, + c text +); +-- partitioning information +SELECT generate_partition_information('multi_column_partitioned'); +ERROR: relation "multi_column_partitioned" does not exist +LINE 1: SELECT generate_partition_information('multi_column_partitio... + ^ +SELECT master_get_table_ddl_events('multi_column_partitioned'); +ERROR: relation "multi_column_partitioned" does not exist +SELECT drop_and_recreate_partitioned_table('multi_column_partitioned'); +ERROR: relation "multi_column_partitioned" does not exist +LINE 1: SELECT drop_and_recreate_partitioned_table('multi_column_par... + ^ +-- partitions and their ranges +ALTER TABLE multi_column_partitioned ATTACH PARTITION multi_column_partition_1 FOR VALUES FROM (1, 10, '250') TO (1, 20, '250'); +ERROR: syntax error at or near "ATTACH" +LINE 1: ALTER TABLE multi_column_partitioned ATTACH PARTITION multi_... + ^ +SELECT generate_alter_table_attach_partition_command('multi_column_partition_1'); + generate_alter_table_attach_partition_command +----------------------------------------------- + +(1 row) + +ALTER TABLE multi_column_partitioned ATTACH PARTITION multi_column_partition_2 FOR VALUES FROM (10, 1000, '2500') TO (UNBOUNDED, UNBOUNDED, UNBOUNDED); +ERROR: syntax error at or near "ATTACH" +LINE 1: ALTER TABLE multi_column_partitioned ATTACH PARTITION multi_... + ^ +SELECT generate_alter_table_attach_partition_command('multi_column_partition_2'); + generate_alter_table_attach_partition_command +----------------------------------------------- + +(1 row) + +SELECT generate_alter_table_detach_partition_command('multi_column_partition_2'); + generate_alter_table_detach_partition_command +----------------------------------------------- + +(1 row) + +-- finally a test with LIST partitioning +CREATE TABLE list_partitioned (col1 NUMERIC, col2 NUMERIC, col3 VARCHAR(10)) PARTITION BY LIST (col1) ; +ERROR: syntax error at or near "PARTITION" +LINE 1: ...ed (col1 NUMERIC, col2 NUMERIC, col3 VARCHAR(10)) PARTITION ... + ^ +SELECT generate_partition_information('list_partitioned'); +ERROR: relation "list_partitioned" does not exist +LINE 1: SELECT generate_partition_information('list_partitioned'); + ^ +SELECT master_get_table_ddl_events('list_partitioned'); +ERROR: relation "list_partitioned" does not exist +SELECT drop_and_recreate_partitioned_table('list_partitioned'); +ERROR: relation "list_partitioned" does not exist +LINE 1: SELECT drop_and_recreate_partitioned_table('list_partitioned... + ^ +CREATE TABLE list_partitioned_1 PARTITION OF list_partitioned FOR VALUES IN (100, 101, 102, 103, 104); +ERROR: syntax error at or near "PARTITION" +LINE 1: CREATE TABLE list_partitioned_1 PARTITION OF list_partitione... + ^ +SELECT generate_alter_table_attach_partition_command('list_partitioned_1'); +ERROR: relation "list_partitioned_1" does not exist +LINE 1: ...ECT generate_alter_table_attach_partition_command('list_part... + ^ +-- also differentiate partitions and inhereted tables +CREATE TABLE cities ( + name text, + population float, + altitude int -- in feet +); +CREATE TABLE capitals ( + state char(2) +) INHERITS (cities); +-- returns true since capitals inherits from cities +SELECT table_inherits('capitals'); + table_inherits +---------------- + t +(1 row) + +-- although date_partition_2006 inherits from its parent +-- returns false since the hierarcy is formed via partitioning +SELECT table_inherits('date_partition_2006'); +ERROR: relation "date_partition_2006" does not exist +LINE 1: SELECT table_inherits('date_partition_2006'); + ^ +-- returns true since cities inherited by capitals +SELECT table_inherited('cities'); + table_inherited +----------------- + t +(1 row) + +-- although date_partitioned_table inherited by its partitions +-- returns false since the hierarcy is formed via partitioning +SELECT table_inherited('date_partitioned_table'); +ERROR: relation "date_partitioned_table" does not exist +LINE 1: SELECT table_inherited('date_partitioned_table'); + ^ +-- also these are not supported +SELECT master_get_table_ddl_events('capitals'); +ERROR: public.capitals is not a regular, foreign, or partitioned table +SELECT master_get_table_ddl_events('cities'); +ERROR: public.cities is not a regular, foreign, or partitioned table +-- dropping parents frop the partitions +DROP TABLE date_partitioned_table, multi_column_partitioned, list_partitioned, partition_parent_schema.parent_table, cities, capitals; +ERROR: table "date_partitioned_table" does not exist diff --git a/src/test/regress/multi_schedule b/src/test/regress/multi_schedule index 1f4b4a48d..8e0e413c1 100644 --- a/src/test/regress/multi_schedule +++ b/src/test/regress/multi_schedule @@ -22,6 +22,11 @@ test: multi_table_ddl test: multi_name_lengths test: multi_metadata_access +# --- +# Tests for partitioning support +# --- +test: multi_partitioning_utils + # ---------- # The following distributed tests depend on creating a partitioned table and # uploading data to it. diff --git a/src/test/regress/sql/multi_partitioning_utils.sql b/src/test/regress/sql/multi_partitioning_utils.sql new file mode 100644 index 000000000..64bbab47f --- /dev/null +++ b/src/test/regress/sql/multi_partitioning_utils.sql @@ -0,0 +1,271 @@ +-- =================================================================== +-- create test functions +-- =================================================================== +CREATE FUNCTION generate_alter_table_detach_partition_command(regclass) + RETURNS text + AS 'citus' + LANGUAGE C STRICT; + +CREATE FUNCTION generate_alter_table_attach_partition_command(regclass) + RETURNS text + AS 'citus' + LANGUAGE C STRICT; + +CREATE FUNCTION generate_partition_information(regclass) + RETURNS text + AS 'citus' + LANGUAGE C STRICT; + +CREATE FUNCTION print_partitions(regclass) + RETURNS text + AS 'citus' + LANGUAGE C STRICT; + +CREATE FUNCTION table_inherits(regclass) + RETURNS bool + AS 'citus' + LANGUAGE C STRICT; + +CREATE FUNCTION table_inherited(regclass) + RETURNS bool + AS 'citus' + LANGUAGE C STRICT; + +CREATE OR REPLACE FUNCTION detach_and_attach_partition(partition_name regclass, parent_table_name regclass) +RETURNS void LANGUAGE plpgsql VOLATILE +AS $function$ +DECLARE + detach_partition_command text := ''; + attach_partition_command text := ''; + command_result text := ''; + +BEGIN + -- first generate the command + SELECT public.generate_alter_table_attach_partition_command(partition_name) INTO attach_partition_command; + + -- now genereate the detach command + SELECT public.generate_alter_table_detach_partition_command(partition_name) INTO detach_partition_command; + + -- later detach the same partition + EXECUTE detach_partition_command; + + -- not attach it again + EXECUTE attach_partition_command; +END; +$function$; + +CREATE OR REPLACE FUNCTION drop_and_recreate_partitioned_table(parent_table_name regclass) +RETURNS void LANGUAGE plpgsql VOLATILE +AS $function$ +DECLARE + command text := ''; + +BEGIN + -- first generate the command + CREATE TABLE partitioned_table_create_commands AS SELECT master_get_table_ddl_events(parent_table_name::text); + + -- later detach the same partition + EXECUTE 'DROP TABLE ' || parent_table_name::text || ';'; + + FOR command IN SELECT * FROM partitioned_table_create_commands + LOOP + -- can do some processing here + EXECUTE command; + END LOOP; + + DROP TABLE partitioned_table_create_commands; + +END; +$function$; + +-- create a partitioned table +CREATE TABLE date_partitioned_table(id int, time date) PARTITION BY RANGE (time); + +-- we should be able to get the partitioning information even if there are no partitions +SELECT generate_partition_information('date_partitioned_table'); + +-- we should be able to drop and re-create the partitioned table using the command that Citus generate +SELECT drop_and_recreate_partitioned_table('date_partitioned_table'); + +-- we should also be able to see the PARTITION BY ... for the parent table +SELECT master_get_table_ddl_events('date_partitioned_table'); + +-- now create the partitions +CREATE TABLE date_partition_2006 PARTITION OF date_partitioned_table FOR VALUES FROM ('2006-01-01') TO ('2007-01-01'); +CREATE TABLE date_partition_2007 PARTITION OF date_partitioned_table FOR VALUES FROM ('2007-01-01') TO ('2008-01-01'); + +-- we should be able to get the partitioning information after the partitions are created +SELECT generate_partition_information('date_partitioned_table'); + +-- lets get the attach partition commands +SELECT generate_alter_table_attach_partition_command('date_partition_2006'); +SELECT generate_alter_table_attach_partition_command('date_partition_2007'); + +-- detach and attach the partition by the command generated by us +\d+ date_partitioned_table + +SELECT detach_and_attach_partition('date_partition_2007', 'date_partitioned_table'); + +-- check that both partitions are visiable +\d+ date_partitioned_table + + +-- make sure that inter shard commands work as expected +-- assume that the shardId is 100 +CREATE TABLE date_partitioned_table_100 (id int, time date) PARTITION BY RANGE (time); +CREATE TABLE date_partition_2007_100 (id int, time date ); + +-- now create the partitioning hierarcy +SELECT worker_apply_inter_shard_ddl_command(referencing_shard:=100, referencing_schema_name:='public', + referenced_shard:=100, referenced_schema_name:='public', + command:='ALTER TABLE date_partitioned_table ATTACH PARTITION date_partition_2007 FOR VALUES FROM (''2007-01-01'') TO (''2008-01-02'')' ); + +-- the hierarcy is successfully created +\d+ date_partitioned_table_100 + +-- Citus can also get the DDL events for the partitions as regular tables +SELECT master_get_table_ddl_events('date_partition_2007_100'); + +-- now break the partitioning hierarcy +SELECT worker_apply_inter_shard_ddl_command(referencing_shard:=100, referencing_schema_name:='public', + referenced_shard:=100, referenced_schema_name:='public', + command:='ALTER TABLE date_partitioned_table DETACH PARTITION date_partition_2007' ); + +-- the hierarcy is successfully broken +\d+ date_partitioned_table_100 + +-- now lets have some more complex partitioning hierarcies with +-- tables on different schemas and constraints on the tables + +CREATE SCHEMA partition_parent_schema; +CREATE TABLE partition_parent_schema.parent_table (id int NOT NULL, time date DEFAULT now()) PARTITION BY RANGE (time); + +CREATE SCHEMA partition_child_1_schema; +CREATE TABLE partition_child_1_schema.child_1 (id int NOT NULL, time date ); + +CREATE SCHEMA partition_child_2_schema; +CREATE TABLE partition_child_2_schema.child_2 (id int NOT NULL, time date ); + +-- we should be able to get the partitioning information even if there are no partitions +SELECT generate_partition_information('partition_parent_schema.parent_table'); + +-- we should be able to drop and re-create the partitioned table using the command that Citus generate +SELECT drop_and_recreate_partitioned_table('partition_parent_schema.parent_table'); + +ALTER TABLE partition_parent_schema.parent_table ATTACH PARTITION partition_child_1_schema.child_1 FOR VALUES FROM ('2009-01-01') TO ('2010-01-02'); + + +SET search_path = 'partition_parent_schema'; + +ALTER TABLE parent_table ATTACH PARTITION partition_child_2_schema.child_2 FOR VALUES FROM ('2006-01-01') TO ('2007-01-01'); + +SELECT public.generate_partition_information('parent_table'); + +-- lets get the attach partition commands +SELECT public.generate_alter_table_attach_partition_command('partition_child_1_schema.child_1'); + +SET search_path = 'partition_child_2_schema'; + +SELECT public.generate_alter_table_attach_partition_command('child_2'); + +SET search_path = 'partition_parent_schema'; + +-- detach and attach the partition by the command generated by us +\d+ parent_table + +SELECT public.detach_and_attach_partition('partition_child_1_schema.child_1', 'parent_table'); + +-- check that both partitions are visiable +\d+ parent_table + +-- some very simple checks that should error out +SELECT public.generate_alter_table_attach_partition_command('parent_table'); +SELECT public.generate_partition_information('partition_child_1_schema.child_1'); +SELECT public.print_partitions('partition_child_1_schema.child_1'); + +-- now pring the partitions +SELECT public.print_partitions('parent_table'); + +SET search_path = 'public'; + +-- test multi column / expression partitioning with UNBOUNDED ranges +CREATE OR REPLACE FUNCTION some_function(input_val text) +RETURNS text LANGUAGE plpgsql IMMUTABLE +AS $function$ +BEGIN + return reverse(input_val); +END; +$function$; + +CREATE TABLE multi_column_partitioned ( + a int, + b int, + c text + ) PARTITION BY RANGE (a, (a+b+1), some_function(upper(c))); + +CREATE TABLE multi_column_partition_1( + a int, + b int, + c text +); + +CREATE TABLE multi_column_partition_2( + a int, + b int, + c text +); + +-- partitioning information +SELECT generate_partition_information('multi_column_partitioned'); +SELECT master_get_table_ddl_events('multi_column_partitioned'); +SELECT drop_and_recreate_partitioned_table('multi_column_partitioned'); + +-- partitions and their ranges +ALTER TABLE multi_column_partitioned ATTACH PARTITION multi_column_partition_1 FOR VALUES FROM (1, 10, '250') TO (1, 20, '250'); +SELECT generate_alter_table_attach_partition_command('multi_column_partition_1'); +ALTER TABLE multi_column_partitioned ATTACH PARTITION multi_column_partition_2 FOR VALUES FROM (10, 1000, '2500') TO (UNBOUNDED, UNBOUNDED, UNBOUNDED); +SELECT generate_alter_table_attach_partition_command('multi_column_partition_2'); +SELECT generate_alter_table_detach_partition_command('multi_column_partition_2'); + +-- finally a test with LIST partitioning +CREATE TABLE list_partitioned (col1 NUMERIC, col2 NUMERIC, col3 VARCHAR(10)) PARTITION BY LIST (col1) ; + +SELECT generate_partition_information('list_partitioned'); +SELECT master_get_table_ddl_events('list_partitioned'); +SELECT drop_and_recreate_partitioned_table('list_partitioned'); + +CREATE TABLE list_partitioned_1 PARTITION OF list_partitioned FOR VALUES IN (100, 101, 102, 103, 104); + +SELECT generate_alter_table_attach_partition_command('list_partitioned_1'); + +-- also differentiate partitions and inhereted tables +CREATE TABLE cities ( + name text, + population float, + altitude int -- in feet +); + +CREATE TABLE capitals ( + state char(2) +) INHERITS (cities); + +-- returns true since capitals inherits from cities +SELECT table_inherits('capitals'); + +-- although date_partition_2006 inherits from its parent +-- returns false since the hierarcy is formed via partitioning +SELECT table_inherits('date_partition_2006'); + +-- returns true since cities inherited by capitals +SELECT table_inherited('cities'); + +-- although date_partitioned_table inherited by its partitions +-- returns false since the hierarcy is formed via partitioning +SELECT table_inherited('date_partitioned_table'); + +-- also these are not supported +SELECT master_get_table_ddl_events('capitals'); +SELECT master_get_table_ddl_events('cities'); + +-- dropping parents frop the partitions +DROP TABLE date_partitioned_table, multi_column_partitioned, list_partitioned, partition_parent_schema.parent_table, cities, capitals; \ No newline at end of file