From fa3a3cde9035092ad2812b7353cfbec9cbc29d2c Mon Sep 17 00:00:00 2001 From: Koval Dmitry Date: Mon, 19 Sep 2022 16:06:03 +0300 Subject: [PATCH v16 1/3] ALTER TABLE MERGE PARTITIONS command --- src/backend/commands/tablecmds.c | 351 ++++++++- src/backend/parser/gram.y | 22 +- src/backend/parser/parse_utilcmd.c | 89 +++ src/backend/partitioning/partbounds.c | 207 +++++ src/include/nodes/parsenodes.h | 13 + src/include/parser/kwlist.h | 1 + src/include/partitioning/partbounds.h | 6 + .../isolation/expected/partition-merge.out | 199 +++++ src/test/isolation/isolation_schedule | 1 + src/test/isolation/specs/partition-merge.spec | 54 ++ .../test_ddl_deparse/test_ddl_deparse.c | 3 + src/test/regress/expected/partition_merge.out | 736 ++++++++++++++++++ src/test/regress/parallel_schedule | 2 +- src/test/regress/sql/partition_merge.sql | 434 +++++++++++ src/tools/pgindent/typedefs.list | 1 + 15 files changed, 2100 insertions(+), 19 deletions(-) create mode 100644 src/test/isolation/expected/partition-merge.out create mode 100644 src/test/isolation/specs/partition-merge.spec create mode 100644 src/test/regress/expected/partition_merge.out create mode 100644 src/test/regress/sql/partition_merge.sql diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c index 3147dddf28..49e9340d5c 100644 --- a/src/backend/commands/tablecmds.c +++ b/src/backend/commands/tablecmds.c @@ -638,6 +638,8 @@ static void ATDetachCheckNoForeignKeyRefs(Relation partition); static char GetAttributeCompression(Oid atttypid, char *compression); static char GetAttributeStorage(Oid atttypid, const char *storagemode); +static void ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel, + PartitionCmd *cmd, AlterTableUtilityContext *context); /* ---------------------------------------------------------------- * DefineRelation @@ -4476,6 +4478,10 @@ AlterTableGetLockLevel(List *cmds) cmd_lockmode = ShareUpdateExclusiveLock; break; + case AT_MergePartitions: + cmd_lockmode = AccessExclusiveLock; + break; + case AT_CheckNotNull: /* @@ -4897,6 +4903,11 @@ ATPrepCmd(List **wqueue, Relation rel, AlterTableCmd *cmd, /* No command-specific prep needed */ pass = AT_PASS_MISC; break; + case AT_MergePartitions: + ATSimplePermissions(cmd->subtype, rel, ATT_TABLE); + /* No command-specific prep needed */ + pass = AT_PASS_MISC; + break; default: /* oops */ elog(ERROR, "unrecognized alter table type: %d", (int) cmd->subtype); @@ -5284,6 +5295,14 @@ ATExecCmd(List **wqueue, AlteredTableInfo *tab, case AT_DetachPartitionFinalize: address = ATExecDetachPartitionFinalize(rel, ((PartitionCmd *) cmd->def)->name); break; + case AT_MergePartitions: + cmd = ATParseTransformCmd(wqueue, tab, rel, cmd, false, lockmode, + cur_pass, context); + Assert(cmd != NULL); + Assert(rel->rd_rel->relkind == RELKIND_PARTITIONED_TABLE); + ATExecMergePartitions(wqueue, tab, rel, (PartitionCmd *) cmd->def, + context); + break; default: /* oops */ elog(ERROR, "unrecognized alter table type: %d", (int) cmd->subtype); @@ -6267,6 +6286,8 @@ alter_table_type_to_string(AlterTableType cmdtype) return "DETACH PARTITION"; case AT_DetachPartitionFinalize: return "DETACH PARTITION ... FINALIZE"; + case AT_MergePartitions: + return "MERGE PARTITIONS"; case AT_AddIdentity: return "ALTER COLUMN ... ADD IDENTITY"; case AT_SetIdentity: @@ -17699,6 +17720,37 @@ QueuePartitionConstraintValidation(List **wqueue, Relation scanrel, } } +/* + * attachPartitionTable: attach new partition to partitioned table + * + * wqueue: the ALTER TABLE work queue; can be NULL when not running as part + * of an ALTER TABLE sequence. + * rel: partitioned relation; + * partition: relation of attached partition; + * bound: bounds of attached relation. + */ +static void +attachPartitionTable(List **wqueue, Relation rel, Relation partition, PartitionBoundSpec *bound) +{ + /* OK to create inheritance. Rest of the checks performed there */ + CreateInheritance(partition, rel); + + /* Update the pg_class entry. */ + StorePartitionBound(partition, rel, bound); + + /* Ensure there exists a correct set of indexes in the partition. */ + AttachPartitionEnsureIndexes(rel, partition); + + /* and triggers */ + CloneRowTriggersToPartition(rel, partition); + + /* + * Clone foreign key constraints. Callee is responsible for setting up + * for phase 3 constraint verification. + */ + CloneForeignKeyConstraints(wqueue, rel, partition); +} + /* * ALTER TABLE ATTACH PARTITION FOR VALUES * @@ -17891,23 +17943,8 @@ ATExecAttachPartition(List **wqueue, Relation rel, PartitionCmd *cmd, check_new_partition_bound(RelationGetRelationName(attachrel), rel, cmd->bound, pstate); - /* OK to create inheritance. Rest of the checks performed there */ - CreateInheritance(attachrel, rel); - - /* Update the pg_class entry. */ - StorePartitionBound(attachrel, rel, cmd->bound); - - /* Ensure there exists a correct set of indexes in the partition. */ - AttachPartitionEnsureIndexes(rel, attachrel); - - /* and triggers */ - CloneRowTriggersToPartition(rel, attachrel); - - /* - * Clone foreign key constraints. Callee is responsible for setting up - * for phase 3 constraint verification. - */ - CloneForeignKeyConstraints(wqueue, rel, attachrel); + /* Attach partition to partitioned table. */ + attachPartitionTable(wqueue, rel, attachrel, cmd->bound); /* * Generate partition constraint from the partition bound specification. @@ -19388,3 +19425,283 @@ GetAttributeStorage(Oid atttypid, const char *storagemode) return cstorage; } + +/* + * createPartitionTable: create table for new partition with given name + * (newPartName) like table (modelRelName) + * + * Emulates command: CREATE TABLE (LIKE + * INCLUDING ALL EXCLUDING INDEXES) + */ +static void +createPartitionTable(RangeVar *newPartName, RangeVar *modelRelName, + AlterTableUtilityContext *context) +{ + CreateStmt *createStmt; + TableLikeClause *tlc; + PlannedStmt *wrapper; + + createStmt = makeNode(CreateStmt); + createStmt->relation = newPartName; + createStmt->tableElts = NIL; + createStmt->inhRelations = NIL; + createStmt->constraints = NIL; + createStmt->options = NIL; + createStmt->oncommit = ONCOMMIT_NOOP; + createStmt->tablespacename = NULL; + createStmt->if_not_exists = false; + + tlc = makeNode(TableLikeClause); + tlc->relation = modelRelName; + + /* + * Indexes will be inherited on "attach new partitions" stage, after data + * moving. + */ + tlc->options = CREATE_TABLE_LIKE_ALL & ~CREATE_TABLE_LIKE_INDEXES; + tlc->relationOid = InvalidOid; + createStmt->tableElts = lappend(createStmt->tableElts, tlc); + + /* Need to make a wrapper PlannedStmt. */ + wrapper = makeNode(PlannedStmt); + wrapper->commandType = CMD_UTILITY; + wrapper->canSetTag = false; + wrapper->utilityStmt = (Node *) createStmt; + wrapper->stmt_location = context->pstmt->stmt_location; + wrapper->stmt_len = context->pstmt->stmt_len; + + ProcessUtility(wrapper, + context->queryString, + false, + PROCESS_UTILITY_SUBCOMMAND, + NULL, + NULL, + None_Receiver, + NULL); +} + +/* + * Struct with context of merged partition + */ +typedef struct MergedPartContext +{ + Relation partRel; /* relation for partition */ +} MergedPartContext; + +/* + * moveMergedTablesRows: scan merged partitions (partContext) of partitioned + * table (rel) and move rows into new partition (newPartRel). + */ +static void +moveMergedTablesRows(Relation rel, List *partContext, Relation newPartRel) +{ + CommandId mycid; + + /* The FSM is empty, so don't bother using it. */ + int ti_options = TABLE_INSERT_SKIP_FSM; + ListCell *listptr; + BulkInsertState bistate; /* state of bulk inserts for partition */ + TupleTableSlot *dstslot; + + mycid = GetCurrentCommandId(true); + + /* Prepare a BulkInsertState for table_tuple_insert. */ + bistate = GetBulkInsertState(); + + /* Create necessary tuple slot. */ + dstslot = MakeSingleTupleTableSlot(RelationGetDescr(newPartRel), + table_slot_callbacks(newPartRel)); + ExecStoreAllNullTuple(dstslot); + + foreach(listptr, partContext) + { + MergedPartContext *pc = (MergedPartContext *) lfirst(listptr); + TupleTableSlot *srcslot; + TupleConversionMap *tuple_map; + TableScanDesc scan; + Snapshot snapshot; + + /* Create tuple slot for new partition. */ + srcslot = MakeSingleTupleTableSlot(RelationGetDescr(pc->partRel), + table_slot_callbacks(pc->partRel)); + + /* + * Map computing for moving attributes of merged partition to new + * partition. + */ + tuple_map = convert_tuples_by_name(RelationGetDescr(pc->partRel), + RelationGetDescr(newPartRel)); + + /* Scan through the rows. */ + snapshot = RegisterSnapshot(GetLatestSnapshot()); + scan = table_beginscan(pc->partRel, snapshot, 0, NULL); + + while (table_scan_getnextslot(scan, ForwardScanDirection, srcslot)) + { + TupleTableSlot *insertslot; + + /* Extract data from old tuple. */ + slot_getallattrs(srcslot); + + if (tuple_map) + { + /* Need to use map for copy attributes. */ + insertslot = execute_attr_map_slot(tuple_map->attrMap, srcslot, dstslot); + } + else + { + /* Copy attributes directly. */ + insertslot = dstslot; + + ExecClearTuple(insertslot); + + memcpy(insertslot->tts_values, srcslot->tts_values, + sizeof(Datum) * srcslot->tts_nvalid); + memcpy(insertslot->tts_isnull, srcslot->tts_isnull, + sizeof(bool) * srcslot->tts_nvalid); + + ExecStoreVirtualTuple(insertslot); + } + + /* Write the tuple out to the new relation. */ + table_tuple_insert(newPartRel, insertslot, mycid, ti_options, bistate); + + CHECK_FOR_INTERRUPTS(); + } + + table_endscan(scan); + UnregisterSnapshot(snapshot); + + if (tuple_map) + free_conversion_map(tuple_map); + + ExecDropSingleTupleTableSlot(srcslot); + } + + ExecDropSingleTupleTableSlot(dstslot); + FreeBulkInsertState(bistate); + + table_finish_bulk_insert(newPartRel, ti_options); +} + +/* + * ALTER TABLE MERGE PARTITIONS INTO + */ +static void +ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation rel, + PartitionCmd *cmd, AlterTableUtilityContext *context) +{ + Relation newPartRel; + ListCell *listptr; + List *partContexts = NIL; + Oid defaultPartOid; + char tmpRelName[NAMEDATALEN]; + RangeVar *mergePartName = cmd->name; + bool isSameName = false; + + /* + * Lock all merged partitions, check them and create list with partitions + * contexts. + */ + foreach(listptr, cmd->partlist) + { + RangeVar *name = (RangeVar *) lfirst(listptr); + MergedPartContext *pc; + + pc = (MergedPartContext *) palloc0(sizeof(MergedPartContext)); + + /* + * We are going to detach and remove this partition: need to use + * exclusive lock for prevent DML-queries to the partition. + */ + pc->partRel = table_openrv(name, AccessExclusiveLock); + + if (pc->partRel->rd_rel->relkind != RELKIND_RELATION) + ereport(ERROR, + (errcode(ERRCODE_WRONG_OBJECT_TYPE), + errmsg("cannot merge non-table partition \"%s\"", + RelationGetRelationName(pc->partRel)))); + + /* + * Checking that two partitions have the same name was before, + * in function transformPartitionCmdForMerge(). + */ + if (equal(name, cmd->name)) + /* One new partition can have the same name as merged partition. */ + isSameName = true; + + /* Store partition context into partitions list. */ + partContexts = lappend(partContexts, pc); + } + + /* Detach all merged partitions. */ + defaultPartOid = + get_default_oid_from_partdesc(RelationGetPartitionDesc(rel, true)); + foreach(listptr, partContexts) + { + MergedPartContext *pc = (MergedPartContext *) lfirst(listptr); + + RemoveInheritance(pc->partRel, rel, false); + /* Do the final part of detaching. */ + DetachPartitionFinalize(rel, pc->partRel, false, defaultPartOid); + } + + /* Create table for new partition, use partitioned table as model. */ + if (isSameName) + { + /* Create partition table with generated temparary name. */ + sprintf(tmpRelName, "merge-%u-%X-tmp", RelationGetRelid(rel), MyProcPid); + mergePartName = makeRangeVar(get_namespace_name(RelationGetNamespace(rel)), + tmpRelName, -1); + } + createPartitionTable(mergePartName, + makeRangeVar(get_namespace_name(RelationGetNamespace(rel)), + RelationGetRelationName(rel), -1), + context); + + /* Open the new partition and acquire exclusive lock on it. */ + newPartRel = table_openrv(mergePartName, AccessExclusiveLock); + + /* Copy data from merged partitions to new partition. */ + moveMergedTablesRows(rel, partContexts, newPartRel); + + /* + * Attach new partition to partitioned table. wqueue = NULL: verification + * for each cloned constraint is not need. + */ + attachPartitionTable(NULL, rel, newPartRel, cmd->bound); + + /* Unlock and drop merged partitions. */ + foreach(listptr, partContexts) + { + ObjectAddress object; + MergedPartContext *pc = (MergedPartContext *) lfirst(listptr); + + /* Get relation id before table_close() call. */ + object.objectId = RelationGetRelid(pc->partRel); + object.classId = RelationRelationId; + object.objectSubId = 0; + + /* Keep the lock until commit. */ + table_close(pc->partRel, NoLock); + + performDeletion(&object, DROP_RESTRICT, 0); + + pfree(pc); + } + + /* Rename new partition if it is needed. */ + if (isSameName) + { + /* + * We must bump the command counter to make the new partition tuple + * visible for rename. + */ + CommandCounterIncrement(); + /* Rename partition. */ + RenameRelationInternal(RelationGetRelid(newPartRel), + cmd->name->relname, false, false); + } + /* Keep the lock until commit. */ + table_close(newPartRel, NoLock); +} diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y index efe88ccf9d..ad8f68b99d 100644 --- a/src/backend/parser/gram.y +++ b/src/backend/parser/gram.y @@ -726,7 +726,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query); ORDER ORDINALITY OTHERS OUT_P OUTER_P OVER OVERLAPS OVERLAY OVERRIDING OWNED OWNER - PARALLEL PARAMETER PARSER PARTIAL PARTITION PASSING PASSWORD + PARALLEL PARAMETER PARSER PARTIAL PARTITION PARTITIONS PASSING PASSWORD PLACING PLANS POLICY POSITION PRECEDING PRECISION PRESERVE PREPARE PREPARED PRIMARY PRIOR PRIVILEGES PROCEDURAL PROCEDURE PROCEDURES PROGRAM PUBLICATION @@ -2280,6 +2280,7 @@ partition_cmd: n->subtype = AT_AttachPartition; cmd->name = $3; cmd->bound = $4; + cmd->partlist = NULL; cmd->concurrent = false; n->def = (Node *) cmd; @@ -2294,6 +2295,7 @@ partition_cmd: n->subtype = AT_DetachPartition; cmd->name = $3; cmd->bound = NULL; + cmd->partlist = NULL; cmd->concurrent = $4; n->def = (Node *) cmd; @@ -2307,6 +2309,21 @@ partition_cmd: n->subtype = AT_DetachPartitionFinalize; cmd->name = $3; cmd->bound = NULL; + cmd->partlist = NULL; + cmd->concurrent = false; + n->def = (Node *) cmd; + $$ = (Node *) n; + } + /* ALTER TABLE MERGE PARTITIONS () INTO */ + | MERGE PARTITIONS '(' qualified_name_list ')' INTO qualified_name + { + AlterTableCmd *n = makeNode(AlterTableCmd); + PartitionCmd *cmd = makeNode(PartitionCmd); + + n->subtype = AT_MergePartitions; + cmd->name = $7; + cmd->bound = NULL; + cmd->partlist = $4; cmd->concurrent = false; n->def = (Node *) cmd; $$ = (Node *) n; @@ -2323,6 +2340,7 @@ index_partition_cmd: n->subtype = AT_AttachPartition; cmd->name = $3; cmd->bound = NULL; + cmd->partlist = NULL; cmd->concurrent = false; n->def = (Node *) cmd; @@ -16905,6 +16923,7 @@ unreserved_keyword: | PARSER | PARTIAL | PARTITION + | PARTITIONS | PASSING | PASSWORD | PLANS @@ -17488,6 +17507,7 @@ bare_label_keyword: | PARSER | PARTIAL | PARTITION + | PARTITIONS | PASSING | PASSWORD | PLACING diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c index 15a1dab8c5..e9fbfc0605 100644 --- a/src/backend/parser/parse_utilcmd.c +++ b/src/backend/parser/parse_utilcmd.c @@ -58,6 +58,8 @@ #include "parser/parse_type.h" #include "parser/parse_utilcmd.h" #include "parser/parser.h" +#include "partitioning/partdesc.h" +#include "partitioning/partbounds.h" #include "rewrite/rewriteManip.h" #include "utils/acl.h" #include "utils/builtins.h" @@ -3263,6 +3265,80 @@ transformRuleStmt(RuleStmt *stmt, const char *queryString, } +/* + * transformPartitionCmdForMerge + * Analyze the ALTER TABLLE ... MERGE PARTITIONS command + * + * Does simple checks for merged partitions. Calculates bound of result + * partition. + */ +static void +transformPartitionCmdForMerge(CreateStmtContext *cxt, PartitionCmd *partcmd) +{ + Oid defaultPartOid; + Oid partOid; + Relation parent = cxt->rel; + PartitionKey key; + char strategy; + ListCell *listptr, + *listptr2; + bool isDefaultPart = false; + List *partOids = NIL; + + if (parent->rd_rel->relkind != RELKIND_PARTITIONED_TABLE) + ereport(ERROR, + (errcode(ERRCODE_INVALID_OBJECT_DEFINITION), + errmsg("\"%s\" is not a partitioned table", RelationGetRelationName(parent)))); + + key = RelationGetPartitionKey(parent); + strategy = get_partition_strategy(key); + + if (strategy == PARTITION_STRATEGY_HASH) + ereport(ERROR, + (errcode(ERRCODE_FEATURE_NOT_SUPPORTED), + errmsg("partition of hash-partitioned table cannot be merged"))); + + /* Is current partition a DEFAULT partition? */ + defaultPartOid = get_default_oid_from_partdesc( + RelationGetPartitionDesc(parent, true)); + + foreach(listptr, partcmd->partlist) + { + RangeVar *name = (RangeVar *) lfirst(listptr); + + /* Partitions in the list should have different names. */ + for_each_cell(listptr2, partcmd->partlist, lnext(partcmd->partlist, listptr)) + { + RangeVar *name2 = (RangeVar *) lfirst(listptr2); + + if (equal(name, name2)) + ereport(ERROR, + (errcode(ERRCODE_DUPLICATE_TABLE), + errmsg("partition with name \"%s\" already used", name->relname)), + parser_errposition(cxt->pstate, name2->location)); + } + + /* Search DEFAULT partition in the list. */ + partOid = RangeVarGetRelid(name, NoLock, false); + if (partOid == defaultPartOid) + isDefaultPart = true; + partOids = lappend_oid(partOids, partOid); + } + + /* Allocate bound of result partition. */ + Assert(partcmd->bound == NULL); + partcmd->bound = makeNode(PartitionBoundSpec); + + /* Fill partition bound. */ + partcmd->bound->strategy = strategy; + partcmd->bound->location = -1; + partcmd->bound->is_default = isDefaultPart; + if (!isDefaultPart) + calculate_partition_bound_for_merge(parent, partcmd->partlist, + partOids, partcmd->bound, + cxt->pstate); +} + /* * transformAlterTableStmt - * parse analysis for ALTER TABLE @@ -3532,6 +3608,19 @@ transformAlterTableStmt(Oid relid, AlterTableStmt *stmt, newcmds = lappend(newcmds, cmd); break; + case AT_MergePartitions: + { + PartitionCmd *partcmd = (PartitionCmd *) cmd->def; + + if (list_length(partcmd->partlist) < 2) + ereport(ERROR, + (errcode(ERRCODE_INVALID_OBJECT_DEFINITION), + errmsg("list of new partitions should contains at least two items"))); + transformPartitionCmdForMerge(&cxt, partcmd); + newcmds = lappend(newcmds, cmd); + break; + } + default: /* diff --git a/src/backend/partitioning/partbounds.c b/src/backend/partitioning/partbounds.c index cf1156b842..032ebae595 100644 --- a/src/backend/partitioning/partbounds.c +++ b/src/backend/partitioning/partbounds.c @@ -4978,3 +4978,210 @@ satisfies_hash_partition(PG_FUNCTION_ARGS) PG_RETURN_BOOL(rowHash % modulus == remainder); } + +/* + * check_two_partitions_bounds_range + * + * (function for BY RANGE partitioning) + * + * This is a helper function for check_partitions_for_split() and + * calculate_partition_bound_for_merge(). + * This function compares upper bound of first_bound and lower bound of + * second_bound. These bounds should be equals except case + * "defaultPart == true" (this means that one of split partitions is DEFAULT). + * In this case upper bound of first_bound can be less than lower bound of + * second_bound because space between of these bounds will be included in + * DEFAULT partition. + * + * parent: partitioned table + * first_name: name of first partition + * first_bound: bound of first partition + * second_name: name of second partition + * second_bound: bound of second partition + * defaultPart: true if one of split partitions is DEFAULT + * pstate: pointer to ParseState struct for determine error position + */ +static void +check_two_partitions_bounds_range(Relation parent, + RangeVar *first_name, + PartitionBoundSpec *first_bound, + RangeVar *second_name, + PartitionBoundSpec *second_bound, + bool defaultPart, + ParseState *pstate) +{ + PartitionKey key = RelationGetPartitionKey(parent); + PartitionRangeBound *first_upper; + PartitionRangeBound *second_lower; + int cmpval; + + Assert(key->strategy == PARTITION_STRATEGY_RANGE); + + first_upper = make_one_partition_rbound(key, -1, first_bound->upperdatums, false); + second_lower = make_one_partition_rbound(key, -1, second_bound->lowerdatums, true); + + /* + * lower1=false (the second to last argument) for correct comparison lower + * and upper bounds. + */ + cmpval = partition_rbound_cmp(key->partnatts, + key->partsupfunc, + key->partcollation, + second_lower->datums, second_lower->kind, + false, first_upper); + if ((!defaultPart && cmpval) || (defaultPart && cmpval < 0)) + { + PartitionRangeDatum *datum = linitial(second_bound->lowerdatums); + + ereport(ERROR, + (errcode(ERRCODE_INVALID_OBJECT_DEFINITION), + errmsg("lower bound of partition \"%s\" conflicts with upper bound of previous partition \"%s\"", + second_name->relname, first_name->relname), + parser_errposition(pstate, datum->location))); + } +} + +/* + * get_partition_bound_spec + * + * Returns description of partition with Oid "partOid" and name "name". + */ +static PartitionBoundSpec * +get_partition_bound_spec(Oid partOid, RangeVar *name) +{ + HeapTuple tuple; + Datum datum; + bool isnull; + PartitionBoundSpec *boundspec = NULL; + + /* Try fetching the tuple from the catcache, for speed. */ + tuple = SearchSysCache1(RELOID, partOid); + if (!HeapTupleIsValid(tuple)) + elog(ERROR, "cache lookup failed for relation \"%s\"", + name->relname); + + datum = SysCacheGetAttr(RELOID, tuple, + Anum_pg_class_relpartbound, + &isnull); + if (isnull) + elog(ERROR, "partition bound for relation \"%s\" is null", + name->relname); + + boundspec = stringToNode(TextDatumGetCString(datum)); + + if (!IsA(boundspec, PartitionBoundSpec)) + elog(ERROR, "expected PartitionBoundSpec for relation \"%s\"", + name->relname); + + ReleaseSysCache(tuple); + return boundspec; +} + +/* + * calculate_partition_bound_for_merge + * + * Calculates the bound of merged partition "spec" by using the bounds of + * partitions to be merged. + * + * parent: partitioned table + * partNames: names of partitions to be merged + * partOids: Oids of partitions to be merged + * spec (out): bounds specification of the merged partition + * pstate: pointer to ParseState struct for determine error position + */ +void +calculate_partition_bound_for_merge(Relation parent, + List *partNames, + List *partOids, + PartitionBoundSpec *spec, + ParseState *pstate) +{ + PartitionKey key = RelationGetPartitionKey(parent); + PartitionBoundSpec *bound; + + Assert(!spec->is_default); + + switch (key->strategy) + { + case PARTITION_STRATEGY_RANGE: + { + int i; + PartitionRangeBound **lower_bounds; + int nparts = list_length(partOids); + List *bounds = NIL; + + lower_bounds = (PartitionRangeBound **) + palloc0(nparts * sizeof(PartitionRangeBound *)); + + /* + * Create array of lower bounds and list of + * PartitionBoundSpec. + */ + for (i = 0; i < nparts; i++) + { + bound = get_partition_bound_spec(list_nth_oid(partOids, i), + (RangeVar *) list_nth(partNames, i)); + + lower_bounds[i] = make_one_partition_rbound(key, i, bound->lowerdatums, true); + bounds = lappend(bounds, bound); + } + + /* Sort array of lower bounds. */ + qsort_arg(lower_bounds, nparts, sizeof(PartitionRangeBound *), + qsort_partition_rbound_cmp, (void *) key); + + /* Ranges of partitions should not overlap. */ + for (i = 1; i < nparts; i++) + { + int index = lower_bounds[i]->index; + int prev_index = lower_bounds[i - 1]->index; + + check_two_partitions_bounds_range(parent, + (RangeVar *) list_nth(partNames, prev_index), + (PartitionBoundSpec *) list_nth(bounds, prev_index), + (RangeVar *) list_nth(partNames, index), + (PartitionBoundSpec *) list_nth(bounds, index), + false, pstate); + } + + /* + * Lower bound of first partition is a lower bound of merged + * partition. + */ + spec->lowerdatums = + ((PartitionBoundSpec *) list_nth(bounds, lower_bounds[0]->index))->lowerdatums; + + /* + * Upper bound of last partition is a upper bound of merged + * partition. + */ + spec->upperdatums = + ((PartitionBoundSpec *) list_nth(bounds, lower_bounds[nparts - 1]->index))->upperdatums; + + pfree(lower_bounds); + list_free(bounds); + break; + } + + case PARTITION_STRATEGY_LIST: + { + ListCell *listptr, + *listptr2; + + /* Consolidate bounds for all partitions in the list. */ + forboth(listptr, partOids, listptr2, partNames) + { + RangeVar *name = (RangeVar *) lfirst(listptr2); + Oid curOid = lfirst_oid(listptr); + + bound = get_partition_bound_spec(curOid, name); + spec->listdatums = list_concat(spec->listdatums, bound->listdatums); + } + break; + } + + default: + elog(ERROR, "unexpected partition strategy: %d", + (int) key->strategy); + } +} diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h index 028588fb33..f5c0625bbf 100644 --- a/src/include/nodes/parsenodes.h +++ b/src/include/nodes/parsenodes.h @@ -932,6 +932,17 @@ typedef struct PartitionRangeDatum int location; /* token location, or -1 if unknown */ } PartitionRangeDatum; +/* + * PartitionDesc - info about single partition for ALTER TABLE SPLIT PARTITION command + */ +typedef struct SinglePartitionSpec +{ + NodeTag type; + + RangeVar *name; /* name of partition */ + PartitionBoundSpec *bound; /* FOR VALUES, if attaching */ +} SinglePartitionSpec; + /* * PartitionCmd - info for ALTER TABLE/INDEX ATTACH/DETACH PARTITION commands */ @@ -940,6 +951,7 @@ typedef struct PartitionCmd NodeTag type; RangeVar *name; /* name of partition to attach/detach */ PartitionBoundSpec *bound; /* FOR VALUES, if attaching */ + List *partlist; /* list of partitions, for SPLIT PARTITION command */ bool concurrent; } PartitionCmd; @@ -2126,6 +2138,7 @@ typedef enum AlterTableType AT_AttachPartition, /* ATTACH PARTITION */ AT_DetachPartition, /* DETACH PARTITION */ AT_DetachPartitionFinalize, /* DETACH PARTITION FINALIZE */ + AT_MergePartitions, /* MERGE PARTITIONS */ AT_AddIdentity, /* ADD IDENTITY */ AT_SetIdentity, /* SET identity column options */ AT_DropIdentity, /* DROP IDENTITY */ diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h index 753e9ee174..2abe9d7d7d 100644 --- a/src/include/parser/kwlist.h +++ b/src/include/parser/kwlist.h @@ -314,6 +314,7 @@ PG_KEYWORD("parameter", PARAMETER, UNRESERVED_KEYWORD, BARE_LABEL) PG_KEYWORD("parser", PARSER, UNRESERVED_KEYWORD, BARE_LABEL) PG_KEYWORD("partial", PARTIAL, UNRESERVED_KEYWORD, BARE_LABEL) PG_KEYWORD("partition", PARTITION, UNRESERVED_KEYWORD, BARE_LABEL) +PG_KEYWORD("partitions", PARTITIONS, UNRESERVED_KEYWORD, BARE_LABEL) PG_KEYWORD("passing", PASSING, UNRESERVED_KEYWORD, BARE_LABEL) PG_KEYWORD("password", PASSWORD, UNRESERVED_KEYWORD, BARE_LABEL) PG_KEYWORD("placing", PLACING, RESERVED_KEYWORD, BARE_LABEL) diff --git a/src/include/partitioning/partbounds.h b/src/include/partitioning/partbounds.h index d2e01f92df..2fe80fb4fc 100644 --- a/src/include/partitioning/partbounds.h +++ b/src/include/partitioning/partbounds.h @@ -143,4 +143,10 @@ extern int partition_range_datum_bsearch(FmgrInfo *partsupfunc, extern int partition_hash_bsearch(PartitionBoundInfo boundinfo, int modulus, int remainder); +extern void calculate_partition_bound_for_merge(Relation parent, + List *partNames, + List *partOids, + PartitionBoundSpec *spec, + ParseState *pstate); + #endif /* PARTBOUNDS_H */ diff --git a/src/test/isolation/expected/partition-merge.out b/src/test/isolation/expected/partition-merge.out new file mode 100644 index 0000000000..98446aaab5 --- /dev/null +++ b/src/test/isolation/expected/partition-merge.out @@ -0,0 +1,199 @@ +Parsed test spec with 2 sessions + +starting permutation: s2b s2i s2c s1b s1merg s2b s2u s1c s2c s2s +step s2b: BEGIN; +step s2i: INSERT INTO tpart VALUES (1, 'text01'); +step s2c: COMMIT; +step s1b: BEGIN; +step s1merg: ALTER TABLE tpart MERGE PARTITIONS (tpart_00_10, tpart_10_20) INTO tpart_00_20; +step s2b: BEGIN; +step s2u: UPDATE tpart SET t = 'text01modif' where i = 1; +step s1c: COMMIT; +step s2u: <... completed> +step s2c: COMMIT; +step s2s: SELECT * FROM tpart; + i|t +--+----------- + 5|text05 +15|text15 + 1|text01modif +25|text25 +35|text35 +(5 rows) + + +starting permutation: s2b s2i s2c s1brr s1merg s2b s2u s1c s2c s2s +step s2b: BEGIN; +step s2i: INSERT INTO tpart VALUES (1, 'text01'); +step s2c: COMMIT; +step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s1merg: ALTER TABLE tpart MERGE PARTITIONS (tpart_00_10, tpart_10_20) INTO tpart_00_20; +step s2b: BEGIN; +step s2u: UPDATE tpart SET t = 'text01modif' where i = 1; +step s1c: COMMIT; +step s2u: <... completed> +step s2c: COMMIT; +step s2s: SELECT * FROM tpart; + i|t +--+----------- + 5|text05 +15|text15 + 1|text01modif +25|text25 +35|text35 +(5 rows) + + +starting permutation: s2b s2i s2c s1bs s1merg s2b s2u s1c s2c s2s +step s2b: BEGIN; +step s2i: INSERT INTO tpart VALUES (1, 'text01'); +step s2c: COMMIT; +step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s1merg: ALTER TABLE tpart MERGE PARTITIONS (tpart_00_10, tpart_10_20) INTO tpart_00_20; +step s2b: BEGIN; +step s2u: UPDATE tpart SET t = 'text01modif' where i = 1; +step s1c: COMMIT; +step s2u: <... completed> +step s2c: COMMIT; +step s2s: SELECT * FROM tpart; + i|t +--+----------- + 5|text05 +15|text15 + 1|text01modif +25|text25 +35|text35 +(5 rows) + + +starting permutation: s2brr s2i s2c s1b s1merg s2b s2u s1c s2c s2s +step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s2i: INSERT INTO tpart VALUES (1, 'text01'); +step s2c: COMMIT; +step s1b: BEGIN; +step s1merg: ALTER TABLE tpart MERGE PARTITIONS (tpart_00_10, tpart_10_20) INTO tpart_00_20; +step s2b: BEGIN; +step s2u: UPDATE tpart SET t = 'text01modif' where i = 1; +step s1c: COMMIT; +step s2u: <... completed> +step s2c: COMMIT; +step s2s: SELECT * FROM tpart; + i|t +--+----------- + 5|text05 +15|text15 + 1|text01modif +25|text25 +35|text35 +(5 rows) + + +starting permutation: s2brr s2i s2c s1brr s1merg s2b s2u s1c s2c s2s +step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s2i: INSERT INTO tpart VALUES (1, 'text01'); +step s2c: COMMIT; +step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s1merg: ALTER TABLE tpart MERGE PARTITIONS (tpart_00_10, tpart_10_20) INTO tpart_00_20; +step s2b: BEGIN; +step s2u: UPDATE tpart SET t = 'text01modif' where i = 1; +step s1c: COMMIT; +step s2u: <... completed> +step s2c: COMMIT; +step s2s: SELECT * FROM tpart; + i|t +--+----------- + 5|text05 +15|text15 + 1|text01modif +25|text25 +35|text35 +(5 rows) + + +starting permutation: s2brr s2i s2c s1bs s1merg s2b s2u s1c s2c s2s +step s2brr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s2i: INSERT INTO tpart VALUES (1, 'text01'); +step s2c: COMMIT; +step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s1merg: ALTER TABLE tpart MERGE PARTITIONS (tpart_00_10, tpart_10_20) INTO tpart_00_20; +step s2b: BEGIN; +step s2u: UPDATE tpart SET t = 'text01modif' where i = 1; +step s1c: COMMIT; +step s2u: <... completed> +step s2c: COMMIT; +step s2s: SELECT * FROM tpart; + i|t +--+----------- + 5|text05 +15|text15 + 1|text01modif +25|text25 +35|text35 +(5 rows) + + +starting permutation: s2bs s2i s2c s1b s1merg s2b s2u s1c s2c s2s +step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s2i: INSERT INTO tpart VALUES (1, 'text01'); +step s2c: COMMIT; +step s1b: BEGIN; +step s1merg: ALTER TABLE tpart MERGE PARTITIONS (tpart_00_10, tpart_10_20) INTO tpart_00_20; +step s2b: BEGIN; +step s2u: UPDATE tpart SET t = 'text01modif' where i = 1; +step s1c: COMMIT; +step s2u: <... completed> +step s2c: COMMIT; +step s2s: SELECT * FROM tpart; + i|t +--+----------- + 5|text05 +15|text15 + 1|text01modif +25|text25 +35|text35 +(5 rows) + + +starting permutation: s2bs s2i s2c s1brr s1merg s2b s2u s1c s2c s2s +step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s2i: INSERT INTO tpart VALUES (1, 'text01'); +step s2c: COMMIT; +step s1brr: BEGIN ISOLATION LEVEL REPEATABLE READ; +step s1merg: ALTER TABLE tpart MERGE PARTITIONS (tpart_00_10, tpart_10_20) INTO tpart_00_20; +step s2b: BEGIN; +step s2u: UPDATE tpart SET t = 'text01modif' where i = 1; +step s1c: COMMIT; +step s2u: <... completed> +step s2c: COMMIT; +step s2s: SELECT * FROM tpart; + i|t +--+----------- + 5|text05 +15|text15 + 1|text01modif +25|text25 +35|text35 +(5 rows) + + +starting permutation: s2bs s2i s2c s1bs s1merg s2b s2u s1c s2c s2s +step s2bs: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s2i: INSERT INTO tpart VALUES (1, 'text01'); +step s2c: COMMIT; +step s1bs: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s1merg: ALTER TABLE tpart MERGE PARTITIONS (tpart_00_10, tpart_10_20) INTO tpart_00_20; +step s2b: BEGIN; +step s2u: UPDATE tpart SET t = 'text01modif' where i = 1; +step s1c: COMMIT; +step s2u: <... completed> +step s2c: COMMIT; +step s2s: SELECT * FROM tpart; + i|t +--+----------- + 5|text05 +15|text15 + 1|text01modif +25|text25 +35|text35 +(5 rows) + diff --git a/src/test/isolation/isolation_schedule b/src/test/isolation/isolation_schedule index 4fc56ae99c..2a98bccbf6 100644 --- a/src/test/isolation/isolation_schedule +++ b/src/test/isolation/isolation_schedule @@ -102,6 +102,7 @@ test: partition-key-update-1 test: partition-key-update-2 test: partition-key-update-3 test: partition-key-update-4 +test: partition-merge test: plpgsql-toast test: cluster-conflict test: cluster-conflict-partition diff --git a/src/test/isolation/specs/partition-merge.spec b/src/test/isolation/specs/partition-merge.spec new file mode 100644 index 0000000000..ec48732c58 --- /dev/null +++ b/src/test/isolation/specs/partition-merge.spec @@ -0,0 +1,54 @@ +# Verify that MERGE operation locks DML operations with partitioned table + +setup +{ + DROP TABLE IF EXISTS tpart; + CREATE TABLE tpart(i int, t text) partition by range(i); + CREATE TABLE tpart_00_10 PARTITION OF tpart FOR VALUES FROM (0) TO (10); + CREATE TABLE tpart_10_20 PARTITION OF tpart FOR VALUES FROM (10) TO (20); + CREATE TABLE tpart_20_30 PARTITION OF tpart FOR VALUES FROM (20) TO (30); + CREATE TABLE tpart_default PARTITION OF tpart DEFAULT; + INSERT INTO tpart VALUES (5, 'text05'); + INSERT INTO tpart VALUES (15, 'text15'); + INSERT INTO tpart VALUES (25, 'text25'); + INSERT INTO tpart VALUES (35, 'text35'); +} + +teardown +{ + DROP TABLE tpart; +} + +session s1 +step s1b { BEGIN; } +step s1brr { BEGIN ISOLATION LEVEL REPEATABLE READ; } +step s1bs { BEGIN ISOLATION LEVEL SERIALIZABLE; } +step s1merg { ALTER TABLE tpart MERGE PARTITIONS (tpart_00_10, tpart_10_20) INTO tpart_00_20; } +step s1c { COMMIT; } + + +session s2 +step s2b { BEGIN; } +step s2brr { BEGIN ISOLATION LEVEL REPEATABLE READ; } +step s2bs { BEGIN ISOLATION LEVEL SERIALIZABLE; } +step s2i { INSERT INTO tpart VALUES (1, 'text01'); } +step s2u { UPDATE tpart SET t = 'text01modif' where i = 1; } +step s2c { COMMIT; } +step s2s { SELECT * FROM tpart; } + + +# s2 inserts row into table. s1 starts MERGE PARTITIONS then +# s2 trying to update inserted row and waits until s1 finished +# MERGE operation. + +permutation s2b s2i s2c s1b s1merg s2b s2u s1c s2c s2s +permutation s2b s2i s2c s1brr s1merg s2b s2u s1c s2c s2s +permutation s2b s2i s2c s1bs s1merg s2b s2u s1c s2c s2s + +permutation s2brr s2i s2c s1b s1merg s2b s2u s1c s2c s2s +permutation s2brr s2i s2c s1brr s1merg s2b s2u s1c s2c s2s +permutation s2brr s2i s2c s1bs s1merg s2b s2u s1c s2c s2s + +permutation s2bs s2i s2c s1b s1merg s2b s2u s1c s2c s2s +permutation s2bs s2i s2c s1brr s1merg s2b s2u s1c s2c s2s +permutation s2bs s2i s2c s1bs s1merg s2b s2u s1c s2c s2s diff --git a/src/test/modules/test_ddl_deparse/test_ddl_deparse.c b/src/test/modules/test_ddl_deparse/test_ddl_deparse.c index b7c6f98577..b4171dd382 100644 --- a/src/test/modules/test_ddl_deparse/test_ddl_deparse.c +++ b/src/test/modules/test_ddl_deparse/test_ddl_deparse.c @@ -297,6 +297,9 @@ get_altertable_subcmdinfo(PG_FUNCTION_ARGS) case AT_DetachPartitionFinalize: strtype = "DETACH PARTITION ... FINALIZE"; break; + case AT_MergePartitions: + strtype = "MERGE PARTITIONS"; + break; case AT_AddIdentity: strtype = "ADD IDENTITY"; break; diff --git a/src/test/regress/expected/partition_merge.out b/src/test/regress/expected/partition_merge.out new file mode 100644 index 0000000000..013ab65961 --- /dev/null +++ b/src/test/regress/expected/partition_merge.out @@ -0,0 +1,736 @@ +-- +-- PARTITIONS_MERGE +-- Tests for "ALTER TABLE ... MERGE PARTITIONS ..." command +-- +CREATE SCHEMA partitions_merge_schema; +SET search_path = partitions_merge_schema, public; +-- +-- BY RANGE partitioning +-- +-- +-- Test for error codes +-- +CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date); +CREATE TABLE sales_dec2021 PARTITION OF sales_range FOR VALUES FROM ('2021-12-01') TO ('2021-12-31'); +CREATE TABLE sales_jan2022 PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-02-01'); +CREATE TABLE sales_feb2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'); +CREATE TABLE sales_mar2022 PARTITION OF sales_range FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'); +CREATE TABLE sales_apr2022 (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date); +CREATE TABLE sales_apr_1 PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-04-15'); +CREATE TABLE sales_apr_2 PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-15') TO ('2022-05-01'); +ALTER TABLE sales_range ATTACH PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'); +CREATE TABLE sales_others PARTITION OF sales_range DEFAULT; +-- ERROR: partition with name "sales_feb2022" already used +ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_feb2022) INTO sales_feb_mar_apr2022; +ERROR: partition with name "sales_feb2022" already used +LINE 1: ...e MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_feb2... + ^ +-- ERROR: cannot merge non-table partition "sales_apr2022" +ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO sales_feb_mar_apr2022; +ERROR: cannot merge non-table partition "sales_apr2022" +-- ERROR: invalid partitions order, partition "sales_mar2022" can not be merged +-- (space between sections sales_jan2022 and sales_mar2022) +ALTER TABLE sales_range MERGE PARTITIONS (sales_jan2022, sales_mar2022) INTO sales_jan_mar2022; +ERROR: lower bound of partition "sales_mar2022" conflicts with upper bound of previous partition "sales_jan2022" +-- ERROR: invalid partitions order, partition "sales_jan2022" can not be merged +-- (space between sections sales_dec2021 and sales_jan2022) +ALTER TABLE sales_range MERGE PARTITIONS (sales_dec2021, sales_jan2022, sales_feb2022) INTO sales_dec_jan_feb2022; +ERROR: lower bound of partition "sales_jan2022" conflicts with upper bound of previous partition "sales_dec2021" +-- NO ERROR: test for custom partitions order +ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_jan2022) INTO sales_jan_feb_mar2022; +SELECT c.oid::pg_catalog.regclass, c.relkind, inhdetachpending, pg_catalog.pg_get_expr(c.relpartbound, c.oid) + FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i + WHERE c.oid = i.inhrelid AND i.inhparent = 'sales_range'::regclass + ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text; + oid | relkind | inhdetachpending | pg_get_expr +-----------------------+---------+------------------+-------------------------------------------------- + sales_apr2022 | p | f | FOR VALUES FROM ('04-01-2022') TO ('05-01-2022') + sales_dec2021 | r | f | FOR VALUES FROM ('12-01-2021') TO ('12-31-2021') + sales_jan_feb_mar2022 | r | f | FOR VALUES FROM ('01-01-2022') TO ('04-01-2022') + sales_others | r | f | DEFAULT +(4 rows) + +DROP TABLE sales_range; +-- +-- Add rows into partitioned table then merge partitions +-- +CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date); +CREATE TABLE sales_jan2022 PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-02-01'); +CREATE TABLE sales_feb2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'); +CREATE TABLE sales_mar2022 PARTITION OF sales_range FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'); +CREATE TABLE sales_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'); +CREATE TABLE sales_others PARTITION OF sales_range DEFAULT; +CREATE INDEX sales_range_sales_date_idx ON sales_range USING btree (sales_date); +INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31'); +INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-10'); +INSERT INTO sales_range VALUES (3, 'Ford', 2000, '2022-04-30'); +INSERT INTO sales_range VALUES (4, 'Ivanov', 750, '2022-04-13'); +INSERT INTO sales_range VALUES (5, 'Deev', 250, '2022-04-07'); +INSERT INTO sales_range VALUES (6, 'Poirot', 150, '2022-02-11'); +INSERT INTO sales_range VALUES (7, 'Li', 175, '2022-03-08'); +INSERT INTO sales_range VALUES (8, 'Ericsson', 185, '2022-02-23'); +INSERT INTO sales_range VALUES (9, 'Muller', 250, '2022-03-11'); +INSERT INTO sales_range VALUES (10, 'Halder', 350, '2022-01-28'); +INSERT INTO sales_range VALUES (11, 'Trump', 380, '2022-04-06'); +INSERT INTO sales_range VALUES (12, 'Plato', 350, '2022-03-19'); +INSERT INTO sales_range VALUES (13, 'Gandi', 377, '2022-01-09'); +INSERT INTO sales_range VALUES (14, 'Smith', 510, '2022-05-04'); +SELECT pg_catalog.pg_get_partkeydef('sales_range'::regclass); + pg_get_partkeydef +-------------------- + RANGE (sales_date) +(1 row) + +-- show partitions with conditions: +SELECT c.oid::pg_catalog.regclass, c.relkind, inhdetachpending, pg_catalog.pg_get_expr(c.relpartbound, c.oid) + FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i + WHERE c.oid = i.inhrelid AND i.inhparent = 'sales_range'::regclass + ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text; + oid | relkind | inhdetachpending | pg_get_expr +---------------+---------+------------------+-------------------------------------------------- + sales_apr2022 | r | f | FOR VALUES FROM ('04-01-2022') TO ('05-01-2022') + sales_feb2022 | r | f | FOR VALUES FROM ('02-01-2022') TO ('03-01-2022') + sales_jan2022 | r | f | FOR VALUES FROM ('01-01-2022') TO ('02-01-2022') + sales_mar2022 | r | f | FOR VALUES FROM ('03-01-2022') TO ('04-01-2022') + sales_others | r | f | DEFAULT +(5 rows) + +ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO sales_feb_mar_apr2022; +-- show partitions with conditions: +SELECT c.oid::pg_catalog.regclass, c.relkind, inhdetachpending, pg_catalog.pg_get_expr(c.relpartbound, c.oid) + FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i + WHERE c.oid = i.inhrelid AND i.inhparent = 'sales_range'::regclass + ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text; + oid | relkind | inhdetachpending | pg_get_expr +-----------------------+---------+------------------+-------------------------------------------------- + sales_feb_mar_apr2022 | r | f | FOR VALUES FROM ('02-01-2022') TO ('05-01-2022') + sales_jan2022 | r | f | FOR VALUES FROM ('01-01-2022') TO ('02-01-2022') + sales_others | r | f | DEFAULT +(3 rows) + +SELECT * FROM pg_indexes WHERE tablename = 'sales_feb_mar_apr2022' and schemaname = 'partitions_merge_schema'; + schemaname | tablename | indexname | tablespace | indexdef +-------------------------+-----------------------+--------------------------------------+------------+----------------------------------------------------------------------------------------------------------------------------- + partitions_merge_schema | sales_feb_mar_apr2022 | sales_feb_mar_apr2022_sales_date_idx | | CREATE INDEX sales_feb_mar_apr2022_sales_date_idx ON partitions_merge_schema.sales_feb_mar_apr2022 USING btree (sales_date) +(1 row) + +SELECT * FROM sales_range; + salesman_id | salesman_name | sales_amount | sales_date +-------------+---------------+--------------+------------ + 1 | May | 1000 | 01-31-2022 + 10 | Halder | 350 | 01-28-2022 + 13 | Gandi | 377 | 01-09-2022 + 2 | Smirnoff | 500 | 02-10-2022 + 6 | Poirot | 150 | 02-11-2022 + 8 | Ericsson | 185 | 02-23-2022 + 7 | Li | 175 | 03-08-2022 + 9 | Muller | 250 | 03-11-2022 + 12 | Plato | 350 | 03-19-2022 + 3 | Ford | 2000 | 04-30-2022 + 4 | Ivanov | 750 | 04-13-2022 + 5 | Deev | 250 | 04-07-2022 + 11 | Trump | 380 | 04-06-2022 + 14 | Smith | 510 | 05-04-2022 +(14 rows) + +SELECT * FROM sales_jan2022; + salesman_id | salesman_name | sales_amount | sales_date +-------------+---------------+--------------+------------ + 1 | May | 1000 | 01-31-2022 + 10 | Halder | 350 | 01-28-2022 + 13 | Gandi | 377 | 01-09-2022 +(3 rows) + +SELECT * FROM sales_feb_mar_apr2022; + salesman_id | salesman_name | sales_amount | sales_date +-------------+---------------+--------------+------------ + 2 | Smirnoff | 500 | 02-10-2022 + 6 | Poirot | 150 | 02-11-2022 + 8 | Ericsson | 185 | 02-23-2022 + 7 | Li | 175 | 03-08-2022 + 9 | Muller | 250 | 03-11-2022 + 12 | Plato | 350 | 03-19-2022 + 3 | Ford | 2000 | 04-30-2022 + 4 | Ivanov | 750 | 04-13-2022 + 5 | Deev | 250 | 04-07-2022 + 11 | Trump | 380 | 04-06-2022 +(10 rows) + +SELECT * FROM sales_others; + salesman_id | salesman_name | sales_amount | sales_date +-------------+---------------+--------------+------------ + 14 | Smith | 510 | 05-04-2022 +(1 row) + +-- Use indexscan for test indexes +SET enable_indexscan = ON; +SET enable_seqscan = OFF; +SELECT * FROM sales_feb_mar_apr2022 where sales_date > '2022-01-01'; + salesman_id | salesman_name | sales_amount | sales_date +-------------+---------------+--------------+------------ + 2 | Smirnoff | 500 | 02-10-2022 + 6 | Poirot | 150 | 02-11-2022 + 8 | Ericsson | 185 | 02-23-2022 + 7 | Li | 175 | 03-08-2022 + 9 | Muller | 250 | 03-11-2022 + 12 | Plato | 350 | 03-19-2022 + 11 | Trump | 380 | 04-06-2022 + 5 | Deev | 250 | 04-07-2022 + 4 | Ivanov | 750 | 04-13-2022 + 3 | Ford | 2000 | 04-30-2022 +(10 rows) + +SET enable_indexscan = ON; +SET enable_seqscan = ON; +DROP TABLE sales_range; +-- +-- Merge some partitions into DEFAULT partition +-- +CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date); +CREATE TABLE sales_jan2022 PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-02-01'); +CREATE TABLE sales_feb2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'); +CREATE TABLE sales_mar2022 PARTITION OF sales_range FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'); +CREATE TABLE sales_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'); +CREATE TABLE sales_others PARTITION OF sales_range DEFAULT; +CREATE INDEX sales_range_sales_date_idx ON sales_range USING btree (sales_date); +INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31'); +INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-10'); +INSERT INTO sales_range VALUES (3, 'Ford', 2000, '2022-04-30'); +INSERT INTO sales_range VALUES (4, 'Ivanov', 750, '2022-04-13'); +INSERT INTO sales_range VALUES (5, 'Deev', 250, '2022-04-07'); +INSERT INTO sales_range VALUES (6, 'Poirot', 150, '2022-02-11'); +INSERT INTO sales_range VALUES (7, 'Li', 175, '2022-03-08'); +INSERT INTO sales_range VALUES (8, 'Ericsson', 185, '2022-02-23'); +INSERT INTO sales_range VALUES (9, 'Muller', 250, '2022-03-11'); +INSERT INTO sales_range VALUES (10, 'Halder', 350, '2022-01-28'); +INSERT INTO sales_range VALUES (11, 'Trump', 380, '2022-04-06'); +INSERT INTO sales_range VALUES (12, 'Plato', 350, '2022-03-19'); +INSERT INTO sales_range VALUES (13, 'Gandi', 377, '2022-01-09'); +INSERT INTO sales_range VALUES (14, 'Smith', 510, '2022-05-04'); +-- Merge partitions (include DEFAULT partition) into partition with the same +-- name +ALTER TABLE sales_range MERGE PARTITIONS (sales_jan2022, sales_mar2022, sales_others) INTO sales_others; +select * from sales_others; + salesman_id | salesman_name | sales_amount | sales_date +-------------+---------------+--------------+------------ + 1 | May | 1000 | 01-31-2022 + 10 | Halder | 350 | 01-28-2022 + 13 | Gandi | 377 | 01-09-2022 + 7 | Li | 175 | 03-08-2022 + 9 | Muller | 250 | 03-11-2022 + 12 | Plato | 350 | 03-19-2022 + 14 | Smith | 510 | 05-04-2022 +(7 rows) + +-- show partitions with conditions: +SELECT c.oid::pg_catalog.regclass, c.relkind, inhdetachpending, pg_catalog.pg_get_expr(c.relpartbound, c.oid) + FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i + WHERE c.oid = i.inhrelid AND i.inhparent = 'sales_range'::regclass + ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text; + oid | relkind | inhdetachpending | pg_get_expr +---------------+---------+------------------+-------------------------------------------------- + sales_apr2022 | r | f | FOR VALUES FROM ('04-01-2022') TO ('05-01-2022') + sales_feb2022 | r | f | FOR VALUES FROM ('02-01-2022') TO ('03-01-2022') + sales_others | r | f | DEFAULT +(3 rows) + +DROP TABLE sales_range; +-- +-- Test for: +-- * composite partition key; +-- * GENERATED column; +-- * column with DEFAULT value. +-- +CREATE TABLE sales_date (salesman_name VARCHAR(30), sales_year INT, sales_month INT, sales_day INT, + sales_date VARCHAR(10) GENERATED ALWAYS AS + (LPAD(sales_year::text, 4, '0') || '.' || LPAD(sales_month::text, 2, '0') || '.' || LPAD(sales_day::text, 2, '0')) STORED, + sales_department VARCHAR(30) DEFAULT 'Sales department') + PARTITION BY RANGE (sales_year, sales_month, sales_day); +CREATE TABLE sales_dec2022 PARTITION OF sales_date FOR VALUES FROM (2021, 12, 1) TO (2022, 1, 1); +CREATE TABLE sales_jan2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1); +CREATE TABLE sales_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1); +CREATE TABLE sales_other PARTITION OF sales_date FOR VALUES FROM (2022, 3, 1) TO (MAXVALUE, MAXVALUE, MAXVALUE); +INSERT INTO sales_date(salesman_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2021, 12, 7); +INSERT INTO sales_date(salesman_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2021, 12, 8); +INSERT INTO sales_date(salesman_name, sales_year, sales_month, sales_day) VALUES ('Manager3', 2022, 1, 1); +INSERT INTO sales_date(salesman_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 2, 4); +INSERT INTO sales_date(salesman_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2022, 1, 2); +INSERT INTO sales_date(salesman_name, sales_year, sales_month, sales_day) VALUES ('Manager3', 2022, 2, 1); +INSERT INTO sales_date(salesman_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 3, 3); +INSERT INTO sales_date(salesman_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2022, 3, 4); +INSERT INTO sales_date(salesman_name, sales_year, sales_month, sales_day) VALUES ('Manager3', 2022, 5, 1); +SELECT * FROM sales_date; + salesman_name | sales_year | sales_month | sales_day | sales_date | sales_department +---------------+------------+-------------+-----------+------------+------------------ + Manager1 | 2021 | 12 | 7 | 2021.12.07 | Sales department + Manager2 | 2021 | 12 | 8 | 2021.12.08 | Sales department + Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department + Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department + Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department + Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department + Manager1 | 2022 | 3 | 3 | 2022.03.03 | Sales department + Manager2 | 2022 | 3 | 4 | 2022.03.04 | Sales department + Manager3 | 2022 | 5 | 1 | 2022.05.01 | Sales department +(9 rows) + +SELECT * FROM sales_dec2022; + salesman_name | sales_year | sales_month | sales_day | sales_date | sales_department +---------------+------------+-------------+-----------+------------+------------------ + Manager1 | 2021 | 12 | 7 | 2021.12.07 | Sales department + Manager2 | 2021 | 12 | 8 | 2021.12.08 | Sales department +(2 rows) + +SELECT * FROM sales_jan2022; + salesman_name | sales_year | sales_month | sales_day | sales_date | sales_department +---------------+------------+-------------+-----------+------------+------------------ + Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department + Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department +(2 rows) + +SELECT * FROM sales_feb2022; + salesman_name | sales_year | sales_month | sales_day | sales_date | sales_department +---------------+------------+-------------+-----------+------------+------------------ + Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department + Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department +(2 rows) + +SELECT * FROM sales_other; + salesman_name | sales_year | sales_month | sales_day | sales_date | sales_department +---------------+------------+-------------+-----------+------------+------------------ + Manager1 | 2022 | 3 | 3 | 2022.03.03 | Sales department + Manager2 | 2022 | 3 | 4 | 2022.03.04 | Sales department + Manager3 | 2022 | 5 | 1 | 2022.05.01 | Sales department +(3 rows) + +ALTER TABLE sales_date MERGE PARTITIONS (sales_jan2022, sales_feb2022) INTO sales_jan_feb2022; +INSERT INTO sales_date(salesman_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 1, 10); +INSERT INTO sales_date(salesman_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2022, 2, 10); +SELECT * FROM sales_date; + salesman_name | sales_year | sales_month | sales_day | sales_date | sales_department +---------------+------------+-------------+-----------+------------+------------------ + Manager1 | 2021 | 12 | 7 | 2021.12.07 | Sales department + Manager2 | 2021 | 12 | 8 | 2021.12.08 | Sales department + Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department + Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department + Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department + Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department + Manager1 | 2022 | 1 | 10 | 2022.01.10 | Sales department + Manager2 | 2022 | 2 | 10 | 2022.02.10 | Sales department + Manager1 | 2022 | 3 | 3 | 2022.03.03 | Sales department + Manager2 | 2022 | 3 | 4 | 2022.03.04 | Sales department + Manager3 | 2022 | 5 | 1 | 2022.05.01 | Sales department +(11 rows) + +SELECT * FROM sales_dec2022; + salesman_name | sales_year | sales_month | sales_day | sales_date | sales_department +---------------+------------+-------------+-----------+------------+------------------ + Manager1 | 2021 | 12 | 7 | 2021.12.07 | Sales department + Manager2 | 2021 | 12 | 8 | 2021.12.08 | Sales department +(2 rows) + +SELECT * FROM sales_jan_feb2022; + salesman_name | sales_year | sales_month | sales_day | sales_date | sales_department +---------------+------------+-------------+-----------+------------+------------------ + Manager3 | 2022 | 1 | 1 | 2022.01.01 | Sales department + Manager2 | 2022 | 1 | 2 | 2022.01.02 | Sales department + Manager1 | 2022 | 2 | 4 | 2022.02.04 | Sales department + Manager3 | 2022 | 2 | 1 | 2022.02.01 | Sales department + Manager1 | 2022 | 1 | 10 | 2022.01.10 | Sales department + Manager2 | 2022 | 2 | 10 | 2022.02.10 | Sales department +(6 rows) + +SELECT * FROM sales_other; + salesman_name | sales_year | sales_month | sales_day | sales_date | sales_department +---------------+------------+-------------+-----------+------------+------------------ + Manager1 | 2022 | 3 | 3 | 2022.03.03 | Sales department + Manager2 | 2022 | 3 | 4 | 2022.03.04 | Sales department + Manager3 | 2022 | 5 | 1 | 2022.05.01 | Sales department +(3 rows) + +DROP TABLE sales_date; +-- +-- Test: merge partitions of partitioned table with triggers +-- +CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id); +CREATE TABLE salesmans01_10 PARTITION OF salesmans FOR VALUES FROM (1) TO (10); +CREATE TABLE salesmans10_20 PARTITION OF salesmans FOR VALUES FROM (10) TO (20); +CREATE TABLE salesmans20_30 PARTITION OF salesmans FOR VALUES FROM (20) TO (30); +CREATE TABLE salesmans30_40 PARTITION OF salesmans FOR VALUES FROM (30) TO (40); +INSERT INTO salesmans VALUES (1, 'Poirot'); +CREATE OR REPLACE FUNCTION after_insert_row_trigger() RETURNS trigger LANGUAGE 'plpgsql' AS $BODY$ +BEGIN + RAISE NOTICE 'trigger(%) called: action = %, when = %, level = %', TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL; + RETURN NULL; +END; +$BODY$; +CREATE TRIGGER salesmans_after_insert_statement_trigger + AFTER INSERT + ON salesmans + FOR EACH STATEMENT + EXECUTE PROCEDURE after_insert_row_trigger('salesmans'); +CREATE TRIGGER salesmans_after_insert_row_trigger + AFTER INSERT + ON salesmans + FOR EACH ROW + EXECUTE PROCEDURE after_insert_row_trigger('salesmans'); +-- 2 triggers should fire here (row + statement): +INSERT INTO salesmans VALUES (10, 'May'); +NOTICE: trigger(salesmans) called: action = INSERT, when = AFTER, level = ROW +NOTICE: trigger(salesmans) called: action = INSERT, when = AFTER, level = STATEMENT +-- 1 trigger should fire here (row): +INSERT INTO salesmans10_20 VALUES (19, 'Ivanov'); +NOTICE: trigger(salesmans) called: action = INSERT, when = AFTER, level = ROW +ALTER TABLE salesmans MERGE PARTITIONS (salesmans10_20, salesmans20_30, salesmans30_40) INTO salesmans10_40; +-- 2 triggers should fire here (row + statement): +INSERT INTO salesmans VALUES (20, 'Smirnoff'); +NOTICE: trigger(salesmans) called: action = INSERT, when = AFTER, level = ROW +NOTICE: trigger(salesmans) called: action = INSERT, when = AFTER, level = STATEMENT +-- 1 trigger should fire here (row): +INSERT INTO salesmans10_40 VALUES (30, 'Ford'); +NOTICE: trigger(salesmans) called: action = INSERT, when = AFTER, level = ROW +SELECT * FROM salesmans01_10; + salesman_id | salesman_name +-------------+--------------- + 1 | Poirot +(1 row) + +SELECT * FROM salesmans10_40; + salesman_id | salesman_name +-------------+--------------- + 10 | May + 19 | Ivanov + 20 | Smirnoff + 30 | Ford +(4 rows) + +DROP TABLE salesmans; +DROP FUNCTION after_insert_row_trigger(); +-- +-- Test: merge partitions with deleted columns +-- +CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id); +CREATE TABLE salesmans01_10 PARTITION OF salesmans FOR VALUES FROM (1) TO (10); +-- Create partitions with some deleted columns: +CREATE TABLE salesmans10_20(d1 VARCHAR(30), salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30)); +CREATE TABLE salesmans20_30(salesman_id INT PRIMARY KEY, d2 INT, salesman_name VARCHAR(30)); +CREATE TABLE salesmans30_40(salesman_id INT PRIMARY KEY, d3 DATE, salesman_name VARCHAR(30)); +INSERT INTO salesmans10_20 VALUES ('dummy value 1', 19, 'Ivanov'); +INSERT INTO salesmans20_30 VALUES (20, 101, 'Smirnoff'); +INSERT INTO salesmans30_40 VALUES (31, now(), 'Popov'); +ALTER TABLE salesmans10_20 DROP COLUMN d1; +ALTER TABLE salesmans20_30 DROP COLUMN d2; +ALTER TABLE salesmans30_40 DROP COLUMN d3; +ALTER TABLE salesmans ATTACH PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20); +ALTER TABLE salesmans ATTACH PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30); +ALTER TABLE salesmans ATTACH PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40); +INSERT INTO salesmans VALUES (1, 'Poirot'); +INSERT INTO salesmans VALUES (10, 'May'); +INSERT INTO salesmans VALUES (30, 'Ford'); +ALTER TABLE salesmans MERGE PARTITIONS (salesmans10_20, salesmans20_30, salesmans30_40) INTO salesmans10_40; +select * from salesmans; + salesman_id | salesman_name +-------------+--------------- + 1 | Poirot + 19 | Ivanov + 10 | May + 20 | Smirnoff + 31 | Popov + 30 | Ford +(6 rows) + +select * from salesmans01_10; + salesman_id | salesman_name +-------------+--------------- + 1 | Poirot +(1 row) + +select * from salesmans10_40; + salesman_id | salesman_name +-------------+--------------- + 19 | Ivanov + 10 | May + 20 | Smirnoff + 31 | Popov + 30 | Ford +(5 rows) + +DROP TABLE salesmans; +-- +-- Test: merge sub-partitions +-- +CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date); +CREATE TABLE sales_jan2022 PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-02-01'); +CREATE TABLE sales_feb2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'); +CREATE TABLE sales_mar2022 PARTITION OF sales_range FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'); +CREATE TABLE sales_apr2022 (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date); +CREATE TABLE sales_apr2022_01_10 PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'); +CREATE TABLE sales_apr2022_10_20 PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'); +CREATE TABLE sales_apr2022_20_30 PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'); +ALTER TABLE sales_range ATTACH PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'); +CREATE TABLE sales_others PARTITION OF sales_range DEFAULT; +CREATE INDEX sales_range_sales_date_idx ON sales_range USING btree (sales_date); +INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31'); +INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-10'); +INSERT INTO sales_range VALUES (3, 'Ford', 2000, '2022-04-30'); +INSERT INTO sales_range VALUES (4, 'Ivanov', 750, '2022-04-13'); +INSERT INTO sales_range VALUES (5, 'Deev', 250, '2022-04-07'); +INSERT INTO sales_range VALUES (6, 'Poirot', 150, '2022-02-11'); +INSERT INTO sales_range VALUES (7, 'Li', 175, '2022-03-08'); +INSERT INTO sales_range VALUES (8, 'Ericsson', 185, '2022-02-23'); +INSERT INTO sales_range VALUES (9, 'Muller', 250, '2022-03-11'); +INSERT INTO sales_range VALUES (10, 'Halder', 350, '2022-01-28'); +INSERT INTO sales_range VALUES (11, 'Trump', 380, '2022-04-06'); +INSERT INTO sales_range VALUES (12, 'Plato', 350, '2022-03-19'); +INSERT INTO sales_range VALUES (13, 'Gandi', 377, '2022-01-09'); +INSERT INTO sales_range VALUES (14, 'Smith', 510, '2022-05-04'); +SELECT * FROM sales_range; + salesman_id | salesman_name | sales_amount | sales_date +-------------+---------------+--------------+------------ + 1 | May | 1000 | 01-31-2022 + 10 | Halder | 350 | 01-28-2022 + 13 | Gandi | 377 | 01-09-2022 + 2 | Smirnoff | 500 | 02-10-2022 + 6 | Poirot | 150 | 02-11-2022 + 8 | Ericsson | 185 | 02-23-2022 + 7 | Li | 175 | 03-08-2022 + 9 | Muller | 250 | 03-11-2022 + 12 | Plato | 350 | 03-19-2022 + 5 | Deev | 250 | 04-07-2022 + 11 | Trump | 380 | 04-06-2022 + 4 | Ivanov | 750 | 04-13-2022 + 3 | Ford | 2000 | 04-30-2022 + 14 | Smith | 510 | 05-04-2022 +(14 rows) + +SELECT * FROM sales_apr2022; + salesman_id | salesman_name | sales_amount | sales_date +-------------+---------------+--------------+------------ + 5 | Deev | 250 | 04-07-2022 + 11 | Trump | 380 | 04-06-2022 + 4 | Ivanov | 750 | 04-13-2022 + 3 | Ford | 2000 | 04-30-2022 +(4 rows) + +SELECT * FROM sales_apr2022_01_10; + salesman_id | salesman_name | sales_amount | sales_date +-------------+---------------+--------------+------------ + 5 | Deev | 250 | 04-07-2022 + 11 | Trump | 380 | 04-06-2022 +(2 rows) + +SELECT * FROM sales_apr2022_10_20; + salesman_id | salesman_name | sales_amount | sales_date +-------------+---------------+--------------+------------ + 4 | Ivanov | 750 | 04-13-2022 +(1 row) + +SELECT * FROM sales_apr2022_20_30; + salesman_id | salesman_name | sales_amount | sales_date +-------------+---------------+--------------+------------ + 3 | Ford | 2000 | 04-30-2022 +(1 row) + +ALTER TABLE sales_apr2022 MERGE PARTITIONS (sales_apr2022_01_10, sales_apr2022_10_20, sales_apr2022_20_30) INTO sales_apr_all; +SELECT * FROM sales_range; + salesman_id | salesman_name | sales_amount | sales_date +-------------+---------------+--------------+------------ + 1 | May | 1000 | 01-31-2022 + 10 | Halder | 350 | 01-28-2022 + 13 | Gandi | 377 | 01-09-2022 + 2 | Smirnoff | 500 | 02-10-2022 + 6 | Poirot | 150 | 02-11-2022 + 8 | Ericsson | 185 | 02-23-2022 + 7 | Li | 175 | 03-08-2022 + 9 | Muller | 250 | 03-11-2022 + 12 | Plato | 350 | 03-19-2022 + 5 | Deev | 250 | 04-07-2022 + 11 | Trump | 380 | 04-06-2022 + 4 | Ivanov | 750 | 04-13-2022 + 3 | Ford | 2000 | 04-30-2022 + 14 | Smith | 510 | 05-04-2022 +(14 rows) + +SELECT * FROM sales_apr2022; + salesman_id | salesman_name | sales_amount | sales_date +-------------+---------------+--------------+------------ + 5 | Deev | 250 | 04-07-2022 + 11 | Trump | 380 | 04-06-2022 + 4 | Ivanov | 750 | 04-13-2022 + 3 | Ford | 2000 | 04-30-2022 +(4 rows) + +SELECT * FROM sales_apr_all; + salesman_id | salesman_name | sales_amount | sales_date +-------------+---------------+--------------+------------ + 5 | Deev | 250 | 04-07-2022 + 11 | Trump | 380 | 04-06-2022 + 4 | Ivanov | 750 | 04-13-2022 + 3 | Ford | 2000 | 04-30-2022 +(4 rows) + +DROP TABLE sales_range; +-- +-- BY LIST partitioning +-- +-- +-- Test: specific errors for BY LIST partitioning +-- +CREATE TABLE sales_list +(salesman_id INT GENERATED ALWAYS AS IDENTITY, + salesman_name VARCHAR(30), + sales_state VARCHAR(20), + sales_amount INT, + sales_date DATE) +PARTITION BY LIST (sales_state); +CREATE TABLE sales_nord PARTITION OF sales_list FOR VALUES IN ('Murmansk', 'St. Petersburg', 'Ukhta'); +CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'); +CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'); +CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'); +CREATE TABLE sales_others PARTITION OF sales_list DEFAULT; +CREATE TABLE sales_list2 (LIKE sales_list) PARTITION BY LIST (sales_state); +CREATE TABLE sales_nord2 PARTITION OF sales_list2 FOR VALUES IN ('Murmansk', 'St. Petersburg', 'Ukhta'); +CREATE TABLE sales_others2 PARTITION OF sales_list2 DEFAULT; +CREATE TABLE sales_external (LIKE sales_list); +CREATE TABLE sales_external2 (vch VARCHAR(5)); +-- ERROR: partition bound for relation "sales_external" is null +ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external) INTO sales_all; +ERROR: partition bound for relation "sales_external" is null +-- ERROR: partition bound for relation "sales_external2" is null +ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external2) INTO sales_all; +ERROR: partition bound for relation "sales_external2" is null +-- ERROR: relation "sales_nord2" is not a partition of relation "sales_list" +ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_nord2, sales_east) INTO sales_all; +ERROR: relation "sales_nord2" is not a partition of relation "sales_list" +DROP TABLE sales_external2; +DROP TABLE sales_external; +DROP TABLE sales_list2; +DROP TABLE sales_list; +-- +-- Test: BY LIST partitioning, MERGE PARTITIONS with data +-- +CREATE TABLE sales_list +(salesman_id INT GENERATED ALWAYS AS IDENTITY, + salesman_name VARCHAR(30), + sales_state VARCHAR(20), + sales_amount INT, + sales_date DATE) +PARTITION BY LIST (sales_state); +CREATE INDEX sales_list_salesman_name_idx ON sales_list USING btree (salesman_name); +CREATE INDEX sales_list_sales_state_idx ON sales_list USING btree (sales_state); +CREATE TABLE sales_nord PARTITION OF sales_list FOR VALUES IN ('Murmansk', 'St. Petersburg', 'Ukhta'); +CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'); +CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'); +CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'); +CREATE TABLE sales_others PARTITION OF sales_list DEFAULT; +INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Trump', 'Magadan', 1000, '2022-03-01'); +INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Smirnoff', 'Smolensk', 500, '2022-03-03'); +INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Ford', 'St. Petersburg', 2000, '2022-03-05'); +INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Ivanov', 'Moscow', 750, '2022-03-04'); +INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Deev', 'Voronezh', 250, '2022-03-07'); +INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Poirot', 'Kazan', 1000, '2022-03-01'); +INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('May', 'Ukhta', 1200, '2022-03-06'); +INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Li', 'Vladivostok', 1150, '2022-03-09'); +INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('May', 'Ukhta', 1200, '2022-03-11'); +INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Halder', 'Murmansk', 800, '2022-03-02'); +INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Muller', 'Bryansk', 650, '2022-03-05'); +INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Smith', 'Volgograd', 350, '2022-03-10'); +INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Gandi', 'Moscow', 150, '2022-03-08'); +INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Plato', 'Voronezh', 950, '2022-03-05'); +-- show partitions with conditions: +SELECT c.oid::pg_catalog.regclass, c.relkind, inhdetachpending, pg_catalog.pg_get_expr(c.relpartbound, c.oid) + FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i + WHERE c.oid = i.inhrelid AND i.inhparent = 'sales_list'::regclass + ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text; + oid | relkind | inhdetachpending | pg_get_expr +---------------+---------+------------------+-------------------------------------------------------- + sales_central | r | f | FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd') + sales_east | r | f | FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok') + sales_nord | r | f | FOR VALUES IN ('Murmansk', 'St. Petersburg', 'Ukhta') + sales_west | r | f | FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk') + sales_others | r | f | DEFAULT +(5 rows) + +ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_central) INTO sales_all; +-- show partitions with conditions: +SELECT c.oid::pg_catalog.regclass, c.relkind, inhdetachpending, pg_catalog.pg_get_expr(c.relpartbound, c.oid) + FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i + WHERE c.oid = i.inhrelid AND i.inhparent = 'sales_list'::regclass + ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text; + oid | relkind | inhdetachpending | pg_get_expr +--------------+---------+------------------+--------------------------------------------------------------------------------------------------------------------------- + sales_all | r | f | FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk', 'Magadan', 'Khabarovsk', 'Vladivostok', 'Moscow', 'Kazan', 'Volgograd') + sales_nord | r | f | FOR VALUES IN ('Murmansk', 'St. Petersburg', 'Ukhta') + sales_others | r | f | DEFAULT +(3 rows) + +SELECT * FROM sales_list; + salesman_id | salesman_name | sales_state | sales_amount | sales_date +-------------+---------------+----------------+--------------+------------ + 2 | Smirnoff | Smolensk | 500 | 03-03-2022 + 5 | Deev | Voronezh | 250 | 03-07-2022 + 11 | Muller | Bryansk | 650 | 03-05-2022 + 14 | Plato | Voronezh | 950 | 03-05-2022 + 1 | Trump | Magadan | 1000 | 03-01-2022 + 8 | Li | Vladivostok | 1150 | 03-09-2022 + 4 | Ivanov | Moscow | 750 | 03-04-2022 + 6 | Poirot | Kazan | 1000 | 03-01-2022 + 12 | Smith | Volgograd | 350 | 03-10-2022 + 13 | Gandi | Moscow | 150 | 03-08-2022 + 3 | Ford | St. Petersburg | 2000 | 03-05-2022 + 7 | May | Ukhta | 1200 | 03-06-2022 + 9 | May | Ukhta | 1200 | 03-11-2022 + 10 | Halder | Murmansk | 800 | 03-02-2022 +(14 rows) + +SELECT * FROM sales_nord; + salesman_id | salesman_name | sales_state | sales_amount | sales_date +-------------+---------------+----------------+--------------+------------ + 3 | Ford | St. Petersburg | 2000 | 03-05-2022 + 7 | May | Ukhta | 1200 | 03-06-2022 + 9 | May | Ukhta | 1200 | 03-11-2022 + 10 | Halder | Murmansk | 800 | 03-02-2022 +(4 rows) + +SELECT * FROM sales_all; + salesman_id | salesman_name | sales_state | sales_amount | sales_date +-------------+---------------+-------------+--------------+------------ + 2 | Smirnoff | Smolensk | 500 | 03-03-2022 + 5 | Deev | Voronezh | 250 | 03-07-2022 + 11 | Muller | Bryansk | 650 | 03-05-2022 + 14 | Plato | Voronezh | 950 | 03-05-2022 + 1 | Trump | Magadan | 1000 | 03-01-2022 + 8 | Li | Vladivostok | 1150 | 03-09-2022 + 4 | Ivanov | Moscow | 750 | 03-04-2022 + 6 | Poirot | Kazan | 1000 | 03-01-2022 + 12 | Smith | Volgograd | 350 | 03-10-2022 + 13 | Gandi | Moscow | 150 | 03-08-2022 +(10 rows) + +-- Use indexscan for test indexes after merge partitions +SET enable_indexscan = ON; +SET enable_seqscan = OFF; +SELECT * FROM sales_all WHERE sales_state = 'Moscow'; + salesman_id | salesman_name | sales_state | sales_amount | sales_date +-------------+---------------+-------------+--------------+------------ + 4 | Ivanov | Moscow | 750 | 03-04-2022 + 13 | Gandi | Moscow | 150 | 03-08-2022 +(2 rows) + +SELECT * FROM sales_list WHERE sales_state = 'Moscow'; + salesman_id | salesman_name | sales_state | sales_amount | sales_date +-------------+---------------+-------------+--------------+------------ + 4 | Ivanov | Moscow | 750 | 03-04-2022 + 13 | Gandi | Moscow | 150 | 03-08-2022 +(2 rows) + +SELECT * FROM sales_list WHERE salesman_name = 'Ivanov'; + salesman_id | salesman_name | sales_state | sales_amount | sales_date +-------------+---------------+-------------+--------------+------------ + 4 | Ivanov | Moscow | 750 | 03-04-2022 +(1 row) + +SET enable_indexscan = ON; +SET enable_seqscan = ON; +DROP TABLE sales_list; +-- +DROP SCHEMA partitions_merge_schema; diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule index 15e015b3d6..41fa8e93c5 100644 --- a/src/test/regress/parallel_schedule +++ b/src/test/regress/parallel_schedule @@ -119,7 +119,7 @@ test: plancache limit plpgsql copy2 temp domain rangefuncs prepare conversion tr # The stats test resets stats, so nothing else needing stats access can be in # this group. # ---------- -test: partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats +test: partition_merge partition_join partition_prune reloptions hash_part indexing partition_aggregate partition_info tuplesort explain compression memoize stats # event_trigger cannot run concurrently with any test that runs DDL # oidjoins is read-only, though, and should run late for best coverage diff --git a/src/test/regress/sql/partition_merge.sql b/src/test/regress/sql/partition_merge.sql new file mode 100644 index 0000000000..8bf90fd621 --- /dev/null +++ b/src/test/regress/sql/partition_merge.sql @@ -0,0 +1,434 @@ +-- +-- PARTITIONS_MERGE +-- Tests for "ALTER TABLE ... MERGE PARTITIONS ..." command +-- + +CREATE SCHEMA partitions_merge_schema; +SET search_path = partitions_merge_schema, public; + +-- +-- BY RANGE partitioning +-- + +-- +-- Test for error codes +-- +CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date); +CREATE TABLE sales_dec2021 PARTITION OF sales_range FOR VALUES FROM ('2021-12-01') TO ('2021-12-31'); +CREATE TABLE sales_jan2022 PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-02-01'); +CREATE TABLE sales_feb2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'); +CREATE TABLE sales_mar2022 PARTITION OF sales_range FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'); + +CREATE TABLE sales_apr2022 (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date); +CREATE TABLE sales_apr_1 PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-04-15'); +CREATE TABLE sales_apr_2 PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-15') TO ('2022-05-01'); +ALTER TABLE sales_range ATTACH PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'); + +CREATE TABLE sales_others PARTITION OF sales_range DEFAULT; + +-- ERROR: partition with name "sales_feb2022" already used +ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_feb2022) INTO sales_feb_mar_apr2022; +-- ERROR: cannot merge non-table partition "sales_apr2022" +ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO sales_feb_mar_apr2022; +-- ERROR: invalid partitions order, partition "sales_mar2022" can not be merged +-- (space between sections sales_jan2022 and sales_mar2022) +ALTER TABLE sales_range MERGE PARTITIONS (sales_jan2022, sales_mar2022) INTO sales_jan_mar2022; +-- ERROR: invalid partitions order, partition "sales_jan2022" can not be merged +-- (space between sections sales_dec2021 and sales_jan2022) +ALTER TABLE sales_range MERGE PARTITIONS (sales_dec2021, sales_jan2022, sales_feb2022) INTO sales_dec_jan_feb2022; + +-- NO ERROR: test for custom partitions order +ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_jan2022) INTO sales_jan_feb_mar2022; + +SELECT c.oid::pg_catalog.regclass, c.relkind, inhdetachpending, pg_catalog.pg_get_expr(c.relpartbound, c.oid) + FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i + WHERE c.oid = i.inhrelid AND i.inhparent = 'sales_range'::regclass + ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text; + +DROP TABLE sales_range; + +-- +-- Add rows into partitioned table then merge partitions +-- +CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date); +CREATE TABLE sales_jan2022 PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-02-01'); +CREATE TABLE sales_feb2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'); +CREATE TABLE sales_mar2022 PARTITION OF sales_range FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'); +CREATE TABLE sales_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'); +CREATE TABLE sales_others PARTITION OF sales_range DEFAULT; +CREATE INDEX sales_range_sales_date_idx ON sales_range USING btree (sales_date); + +INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31'); +INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-10'); +INSERT INTO sales_range VALUES (3, 'Ford', 2000, '2022-04-30'); +INSERT INTO sales_range VALUES (4, 'Ivanov', 750, '2022-04-13'); +INSERT INTO sales_range VALUES (5, 'Deev', 250, '2022-04-07'); +INSERT INTO sales_range VALUES (6, 'Poirot', 150, '2022-02-11'); +INSERT INTO sales_range VALUES (7, 'Li', 175, '2022-03-08'); +INSERT INTO sales_range VALUES (8, 'Ericsson', 185, '2022-02-23'); +INSERT INTO sales_range VALUES (9, 'Muller', 250, '2022-03-11'); +INSERT INTO sales_range VALUES (10, 'Halder', 350, '2022-01-28'); +INSERT INTO sales_range VALUES (11, 'Trump', 380, '2022-04-06'); +INSERT INTO sales_range VALUES (12, 'Plato', 350, '2022-03-19'); +INSERT INTO sales_range VALUES (13, 'Gandi', 377, '2022-01-09'); +INSERT INTO sales_range VALUES (14, 'Smith', 510, '2022-05-04'); + +SELECT pg_catalog.pg_get_partkeydef('sales_range'::regclass); + +-- show partitions with conditions: +SELECT c.oid::pg_catalog.regclass, c.relkind, inhdetachpending, pg_catalog.pg_get_expr(c.relpartbound, c.oid) + FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i + WHERE c.oid = i.inhrelid AND i.inhparent = 'sales_range'::regclass + ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text; + +ALTER TABLE sales_range MERGE PARTITIONS (sales_feb2022, sales_mar2022, sales_apr2022) INTO sales_feb_mar_apr2022; + +-- show partitions with conditions: +SELECT c.oid::pg_catalog.regclass, c.relkind, inhdetachpending, pg_catalog.pg_get_expr(c.relpartbound, c.oid) + FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i + WHERE c.oid = i.inhrelid AND i.inhparent = 'sales_range'::regclass + ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text; + +SELECT * FROM pg_indexes WHERE tablename = 'sales_feb_mar_apr2022' and schemaname = 'partitions_merge_schema'; + +SELECT * FROM sales_range; +SELECT * FROM sales_jan2022; +SELECT * FROM sales_feb_mar_apr2022; +SELECT * FROM sales_others; + +-- Use indexscan for test indexes +SET enable_indexscan = ON; +SET enable_seqscan = OFF; + +SELECT * FROM sales_feb_mar_apr2022 where sales_date > '2022-01-01'; + +SET enable_indexscan = ON; +SET enable_seqscan = ON; + +DROP TABLE sales_range; + +-- +-- Merge some partitions into DEFAULT partition +-- +CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date); +CREATE TABLE sales_jan2022 PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-02-01'); +CREATE TABLE sales_feb2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'); +CREATE TABLE sales_mar2022 PARTITION OF sales_range FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'); +CREATE TABLE sales_apr2022 PARTITION OF sales_range FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'); +CREATE TABLE sales_others PARTITION OF sales_range DEFAULT; +CREATE INDEX sales_range_sales_date_idx ON sales_range USING btree (sales_date); + +INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31'); +INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-10'); +INSERT INTO sales_range VALUES (3, 'Ford', 2000, '2022-04-30'); +INSERT INTO sales_range VALUES (4, 'Ivanov', 750, '2022-04-13'); +INSERT INTO sales_range VALUES (5, 'Deev', 250, '2022-04-07'); +INSERT INTO sales_range VALUES (6, 'Poirot', 150, '2022-02-11'); +INSERT INTO sales_range VALUES (7, 'Li', 175, '2022-03-08'); +INSERT INTO sales_range VALUES (8, 'Ericsson', 185, '2022-02-23'); +INSERT INTO sales_range VALUES (9, 'Muller', 250, '2022-03-11'); +INSERT INTO sales_range VALUES (10, 'Halder', 350, '2022-01-28'); +INSERT INTO sales_range VALUES (11, 'Trump', 380, '2022-04-06'); +INSERT INTO sales_range VALUES (12, 'Plato', 350, '2022-03-19'); +INSERT INTO sales_range VALUES (13, 'Gandi', 377, '2022-01-09'); +INSERT INTO sales_range VALUES (14, 'Smith', 510, '2022-05-04'); + +-- Merge partitions (include DEFAULT partition) into partition with the same +-- name +ALTER TABLE sales_range MERGE PARTITIONS (sales_jan2022, sales_mar2022, sales_others) INTO sales_others; + +select * from sales_others; + +-- show partitions with conditions: +SELECT c.oid::pg_catalog.regclass, c.relkind, inhdetachpending, pg_catalog.pg_get_expr(c.relpartbound, c.oid) + FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i + WHERE c.oid = i.inhrelid AND i.inhparent = 'sales_range'::regclass + ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text; + +DROP TABLE sales_range; + +-- +-- Test for: +-- * composite partition key; +-- * GENERATED column; +-- * column with DEFAULT value. +-- +CREATE TABLE sales_date (salesman_name VARCHAR(30), sales_year INT, sales_month INT, sales_day INT, + sales_date VARCHAR(10) GENERATED ALWAYS AS + (LPAD(sales_year::text, 4, '0') || '.' || LPAD(sales_month::text, 2, '0') || '.' || LPAD(sales_day::text, 2, '0')) STORED, + sales_department VARCHAR(30) DEFAULT 'Sales department') + PARTITION BY RANGE (sales_year, sales_month, sales_day); + +CREATE TABLE sales_dec2022 PARTITION OF sales_date FOR VALUES FROM (2021, 12, 1) TO (2022, 1, 1); +CREATE TABLE sales_jan2022 PARTITION OF sales_date FOR VALUES FROM (2022, 1, 1) TO (2022, 2, 1); +CREATE TABLE sales_feb2022 PARTITION OF sales_date FOR VALUES FROM (2022, 2, 1) TO (2022, 3, 1); +CREATE TABLE sales_other PARTITION OF sales_date FOR VALUES FROM (2022, 3, 1) TO (MAXVALUE, MAXVALUE, MAXVALUE); + +INSERT INTO sales_date(salesman_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2021, 12, 7); +INSERT INTO sales_date(salesman_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2021, 12, 8); +INSERT INTO sales_date(salesman_name, sales_year, sales_month, sales_day) VALUES ('Manager3', 2022, 1, 1); +INSERT INTO sales_date(salesman_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 2, 4); +INSERT INTO sales_date(salesman_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2022, 1, 2); +INSERT INTO sales_date(salesman_name, sales_year, sales_month, sales_day) VALUES ('Manager3', 2022, 2, 1); +INSERT INTO sales_date(salesman_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 3, 3); +INSERT INTO sales_date(salesman_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2022, 3, 4); +INSERT INTO sales_date(salesman_name, sales_year, sales_month, sales_day) VALUES ('Manager3', 2022, 5, 1); + +SELECT * FROM sales_date; +SELECT * FROM sales_dec2022; +SELECT * FROM sales_jan2022; +SELECT * FROM sales_feb2022; +SELECT * FROM sales_other; + +ALTER TABLE sales_date MERGE PARTITIONS (sales_jan2022, sales_feb2022) INTO sales_jan_feb2022; + +INSERT INTO sales_date(salesman_name, sales_year, sales_month, sales_day) VALUES ('Manager1', 2022, 1, 10); +INSERT INTO sales_date(salesman_name, sales_year, sales_month, sales_day) VALUES ('Manager2', 2022, 2, 10); + +SELECT * FROM sales_date; +SELECT * FROM sales_dec2022; +SELECT * FROM sales_jan_feb2022; +SELECT * FROM sales_other; + +DROP TABLE sales_date; + +-- +-- Test: merge partitions of partitioned table with triggers +-- +CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id); + +CREATE TABLE salesmans01_10 PARTITION OF salesmans FOR VALUES FROM (1) TO (10); +CREATE TABLE salesmans10_20 PARTITION OF salesmans FOR VALUES FROM (10) TO (20); +CREATE TABLE salesmans20_30 PARTITION OF salesmans FOR VALUES FROM (20) TO (30); +CREATE TABLE salesmans30_40 PARTITION OF salesmans FOR VALUES FROM (30) TO (40); + +INSERT INTO salesmans VALUES (1, 'Poirot'); + +CREATE OR REPLACE FUNCTION after_insert_row_trigger() RETURNS trigger LANGUAGE 'plpgsql' AS $BODY$ +BEGIN + RAISE NOTICE 'trigger(%) called: action = %, when = %, level = %', TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL; + RETURN NULL; +END; +$BODY$; + +CREATE TRIGGER salesmans_after_insert_statement_trigger + AFTER INSERT + ON salesmans + FOR EACH STATEMENT + EXECUTE PROCEDURE after_insert_row_trigger('salesmans'); + +CREATE TRIGGER salesmans_after_insert_row_trigger + AFTER INSERT + ON salesmans + FOR EACH ROW + EXECUTE PROCEDURE after_insert_row_trigger('salesmans'); + +-- 2 triggers should fire here (row + statement): +INSERT INTO salesmans VALUES (10, 'May'); +-- 1 trigger should fire here (row): +INSERT INTO salesmans10_20 VALUES (19, 'Ivanov'); + +ALTER TABLE salesmans MERGE PARTITIONS (salesmans10_20, salesmans20_30, salesmans30_40) INTO salesmans10_40; + +-- 2 triggers should fire here (row + statement): +INSERT INTO salesmans VALUES (20, 'Smirnoff'); +-- 1 trigger should fire here (row): +INSERT INTO salesmans10_40 VALUES (30, 'Ford'); + +SELECT * FROM salesmans01_10; +SELECT * FROM salesmans10_40; + +DROP TABLE salesmans; +DROP FUNCTION after_insert_row_trigger(); + +-- +-- Test: merge partitions with deleted columns +-- +CREATE TABLE salesmans(salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30)) PARTITION BY RANGE (salesman_id); + +CREATE TABLE salesmans01_10 PARTITION OF salesmans FOR VALUES FROM (1) TO (10); +-- Create partitions with some deleted columns: +CREATE TABLE salesmans10_20(d1 VARCHAR(30), salesman_id INT PRIMARY KEY, salesman_name VARCHAR(30)); +CREATE TABLE salesmans20_30(salesman_id INT PRIMARY KEY, d2 INT, salesman_name VARCHAR(30)); +CREATE TABLE salesmans30_40(salesman_id INT PRIMARY KEY, d3 DATE, salesman_name VARCHAR(30)); + +INSERT INTO salesmans10_20 VALUES ('dummy value 1', 19, 'Ivanov'); +INSERT INTO salesmans20_30 VALUES (20, 101, 'Smirnoff'); +INSERT INTO salesmans30_40 VALUES (31, now(), 'Popov'); + +ALTER TABLE salesmans10_20 DROP COLUMN d1; +ALTER TABLE salesmans20_30 DROP COLUMN d2; +ALTER TABLE salesmans30_40 DROP COLUMN d3; + +ALTER TABLE salesmans ATTACH PARTITION salesmans10_20 FOR VALUES FROM (10) TO (20); +ALTER TABLE salesmans ATTACH PARTITION salesmans20_30 FOR VALUES FROM (20) TO (30); +ALTER TABLE salesmans ATTACH PARTITION salesmans30_40 FOR VALUES FROM (30) TO (40); + +INSERT INTO salesmans VALUES (1, 'Poirot'); +INSERT INTO salesmans VALUES (10, 'May'); +INSERT INTO salesmans VALUES (30, 'Ford'); + +ALTER TABLE salesmans MERGE PARTITIONS (salesmans10_20, salesmans20_30, salesmans30_40) INTO salesmans10_40; + +select * from salesmans; +select * from salesmans01_10; +select * from salesmans10_40; + +DROP TABLE salesmans; + +-- +-- Test: merge sub-partitions +-- +CREATE TABLE sales_range (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date); +CREATE TABLE sales_jan2022 PARTITION OF sales_range FOR VALUES FROM ('2022-01-01') TO ('2022-02-01'); +CREATE TABLE sales_feb2022 PARTITION OF sales_range FOR VALUES FROM ('2022-02-01') TO ('2022-03-01'); +CREATE TABLE sales_mar2022 PARTITION OF sales_range FOR VALUES FROM ('2022-03-01') TO ('2022-04-01'); + +CREATE TABLE sales_apr2022 (salesman_id INT, salesman_name VARCHAR(30), sales_amount INT, sales_date DATE) PARTITION BY RANGE (sales_date); +CREATE TABLE sales_apr2022_01_10 PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-04-10'); +CREATE TABLE sales_apr2022_10_20 PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-10') TO ('2022-04-20'); +CREATE TABLE sales_apr2022_20_30 PARTITION OF sales_apr2022 FOR VALUES FROM ('2022-04-20') TO ('2022-05-01'); +ALTER TABLE sales_range ATTACH PARTITION sales_apr2022 FOR VALUES FROM ('2022-04-01') TO ('2022-05-01'); + +CREATE TABLE sales_others PARTITION OF sales_range DEFAULT; + +CREATE INDEX sales_range_sales_date_idx ON sales_range USING btree (sales_date); + +INSERT INTO sales_range VALUES (1, 'May', 1000, '2022-01-31'); +INSERT INTO sales_range VALUES (2, 'Smirnoff', 500, '2022-02-10'); +INSERT INTO sales_range VALUES (3, 'Ford', 2000, '2022-04-30'); +INSERT INTO sales_range VALUES (4, 'Ivanov', 750, '2022-04-13'); +INSERT INTO sales_range VALUES (5, 'Deev', 250, '2022-04-07'); +INSERT INTO sales_range VALUES (6, 'Poirot', 150, '2022-02-11'); +INSERT INTO sales_range VALUES (7, 'Li', 175, '2022-03-08'); +INSERT INTO sales_range VALUES (8, 'Ericsson', 185, '2022-02-23'); +INSERT INTO sales_range VALUES (9, 'Muller', 250, '2022-03-11'); +INSERT INTO sales_range VALUES (10, 'Halder', 350, '2022-01-28'); +INSERT INTO sales_range VALUES (11, 'Trump', 380, '2022-04-06'); +INSERT INTO sales_range VALUES (12, 'Plato', 350, '2022-03-19'); +INSERT INTO sales_range VALUES (13, 'Gandi', 377, '2022-01-09'); +INSERT INTO sales_range VALUES (14, 'Smith', 510, '2022-05-04'); + +SELECT * FROM sales_range; +SELECT * FROM sales_apr2022; +SELECT * FROM sales_apr2022_01_10; +SELECT * FROM sales_apr2022_10_20; +SELECT * FROM sales_apr2022_20_30; + +ALTER TABLE sales_apr2022 MERGE PARTITIONS (sales_apr2022_01_10, sales_apr2022_10_20, sales_apr2022_20_30) INTO sales_apr_all; + +SELECT * FROM sales_range; +SELECT * FROM sales_apr2022; +SELECT * FROM sales_apr_all; + +DROP TABLE sales_range; + +-- +-- BY LIST partitioning +-- + +-- +-- Test: specific errors for BY LIST partitioning +-- +CREATE TABLE sales_list +(salesman_id INT GENERATED ALWAYS AS IDENTITY, + salesman_name VARCHAR(30), + sales_state VARCHAR(20), + sales_amount INT, + sales_date DATE) +PARTITION BY LIST (sales_state); +CREATE TABLE sales_nord PARTITION OF sales_list FOR VALUES IN ('Murmansk', 'St. Petersburg', 'Ukhta'); +CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'); +CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'); +CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'); +CREATE TABLE sales_others PARTITION OF sales_list DEFAULT; + + +CREATE TABLE sales_list2 (LIKE sales_list) PARTITION BY LIST (sales_state); +CREATE TABLE sales_nord2 PARTITION OF sales_list2 FOR VALUES IN ('Murmansk', 'St. Petersburg', 'Ukhta'); +CREATE TABLE sales_others2 PARTITION OF sales_list2 DEFAULT; + + +CREATE TABLE sales_external (LIKE sales_list); +CREATE TABLE sales_external2 (vch VARCHAR(5)); + +-- ERROR: partition bound for relation "sales_external" is null +ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external) INTO sales_all; +-- ERROR: partition bound for relation "sales_external2" is null +ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_external2) INTO sales_all; +-- ERROR: relation "sales_nord2" is not a partition of relation "sales_list" +ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_nord2, sales_east) INTO sales_all; + +DROP TABLE sales_external2; +DROP TABLE sales_external; +DROP TABLE sales_list2; +DROP TABLE sales_list; + +-- +-- Test: BY LIST partitioning, MERGE PARTITIONS with data +-- +CREATE TABLE sales_list +(salesman_id INT GENERATED ALWAYS AS IDENTITY, + salesman_name VARCHAR(30), + sales_state VARCHAR(20), + sales_amount INT, + sales_date DATE) +PARTITION BY LIST (sales_state); + +CREATE INDEX sales_list_salesman_name_idx ON sales_list USING btree (salesman_name); +CREATE INDEX sales_list_sales_state_idx ON sales_list USING btree (sales_state); + +CREATE TABLE sales_nord PARTITION OF sales_list FOR VALUES IN ('Murmansk', 'St. Petersburg', 'Ukhta'); +CREATE TABLE sales_west PARTITION OF sales_list FOR VALUES IN ('Voronezh', 'Smolensk', 'Bryansk'); +CREATE TABLE sales_east PARTITION OF sales_list FOR VALUES IN ('Magadan', 'Khabarovsk', 'Vladivostok'); +CREATE TABLE sales_central PARTITION OF sales_list FOR VALUES IN ('Moscow', 'Kazan', 'Volgograd'); +CREATE TABLE sales_others PARTITION OF sales_list DEFAULT; + +INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Trump', 'Magadan', 1000, '2022-03-01'); +INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Smirnoff', 'Smolensk', 500, '2022-03-03'); +INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Ford', 'St. Petersburg', 2000, '2022-03-05'); +INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Ivanov', 'Moscow', 750, '2022-03-04'); +INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Deev', 'Voronezh', 250, '2022-03-07'); +INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Poirot', 'Kazan', 1000, '2022-03-01'); +INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('May', 'Ukhta', 1200, '2022-03-06'); +INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Li', 'Vladivostok', 1150, '2022-03-09'); +INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('May', 'Ukhta', 1200, '2022-03-11'); +INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Halder', 'Murmansk', 800, '2022-03-02'); +INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Muller', 'Bryansk', 650, '2022-03-05'); +INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Smith', 'Volgograd', 350, '2022-03-10'); +INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Gandi', 'Moscow', 150, '2022-03-08'); +INSERT INTO sales_list (salesman_name, sales_state, sales_amount, sales_date) VALUES ('Plato', 'Voronezh', 950, '2022-03-05'); + +-- show partitions with conditions: +SELECT c.oid::pg_catalog.regclass, c.relkind, inhdetachpending, pg_catalog.pg_get_expr(c.relpartbound, c.oid) + FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i + WHERE c.oid = i.inhrelid AND i.inhparent = 'sales_list'::regclass + ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text; + +ALTER TABLE sales_list MERGE PARTITIONS (sales_west, sales_east, sales_central) INTO sales_all; + +-- show partitions with conditions: +SELECT c.oid::pg_catalog.regclass, c.relkind, inhdetachpending, pg_catalog.pg_get_expr(c.relpartbound, c.oid) + FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i + WHERE c.oid = i.inhrelid AND i.inhparent = 'sales_list'::regclass + ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_catalog.regclass::pg_catalog.text; + +SELECT * FROM sales_list; +SELECT * FROM sales_nord; +SELECT * FROM sales_all; + +-- Use indexscan for test indexes after merge partitions +SET enable_indexscan = ON; +SET enable_seqscan = OFF; + +SELECT * FROM sales_all WHERE sales_state = 'Moscow'; +SELECT * FROM sales_list WHERE sales_state = 'Moscow'; +SELECT * FROM sales_list WHERE salesman_name = 'Ivanov'; + +SET enable_indexscan = ON; +SET enable_seqscan = ON; + +DROP TABLE sales_list; + +-- +DROP SCHEMA partitions_merge_schema; diff --git a/src/tools/pgindent/typedefs.list b/src/tools/pgindent/typedefs.list index 0b7bc45767..8775bf37d3 100644 --- a/src/tools/pgindent/typedefs.list +++ b/src/tools/pgindent/typedefs.list @@ -2534,6 +2534,7 @@ SimpleStats SimpleStringList SimpleStringListCell SingleBoundSortItem +SinglePartitionSpec Size SkipPages SlabBlock -- 2.31.0.windows.1